From 9a6ebd4c6bf4b3e4f9021dd986a3ad79d196f591 Mon Sep 17 00:00:00 2001 From: jbranchaud Date: Sun, 3 Nov 2024 23:19:17 -0600 Subject: [PATCH] Add Table Names Are Treated As Lower-Case By Default as a Postgres TIL --- README.md | 3 +- ...es-are-treated-as-lower-case-by-default.md | 80 +++++++++++++++++++ 2 files changed, 82 insertions(+), 1 deletion(-) create mode 100644 postgres/table-names-are-treated-as-lower-case-by-default.md diff --git a/README.md b/README.md index 99ab3c9..c20435e 100644 --- a/README.md +++ b/README.md @@ -10,7 +10,7 @@ pairing with smart people at Hashrocket. For a steady stream of TILs, [sign up for my newsletter](https://crafty-builder-6996.ck.page/e169c61186). -_1494 TILs and counting..._ +_1495 TILs and counting..._ --- @@ -839,6 +839,7 @@ _1494 TILs and counting..._ - [Survey Of User-Defined Ordering Of Records](postgres/survey-of-user-defined-ordering-of-records.md) - [Switch Non-Castable Column Type With Using Clause](postgres/switch-non-castable-column-type-with-using-clause.md) - [Switch The Running Postgres Server Version](postgres/switch-the-running-postgres-server-version.md) +- [Table Names Are Treated As Lower-Case By Default](postgres/table-names-are-treated-as-lower-case-by-default.md) - [Temporarily Disable Triggers](postgres/temporarily-disable-triggers.md) - [Temporary Tables](postgres/temporary-tables.md) - [Terminating A Connection](postgres/terminating-a-connection.md) diff --git a/postgres/table-names-are-treated-as-lower-case-by-default.md b/postgres/table-names-are-treated-as-lower-case-by-default.md new file mode 100644 index 0000000..9bb0447 --- /dev/null +++ b/postgres/table-names-are-treated-as-lower-case-by-default.md @@ -0,0 +1,80 @@ +# Table Names Are Treated As Lower-Case By Default + +This one is a bit unintuitive and can cause some real confusion -- when you +create a table in PostgreSQL, any casing is ignored, it is treated as +lower-case. Let's see it to believe it: + +```sql +> create table BookMarks ( + id integer generated always as identity primary key, + location text not null + ); + +> \d ++--------+--------------------+----------+----------+ +| Schema | Name | Type | Owner | +|--------+--------------------+----------+----------| +| public | bookmarks | table | postgres | +| public | bookmarks_id_seq | sequence | postgres | ++--------+--------------------+----------+----------+ +``` + +Notice that when we list our tables, the uppercase `M` and `B` are gone. That's +because Postgres folds away the casing when processing the table name +identifier. + +It doesn't matter how we refer to it for queries: + +```sql +> select * from BookMarks; ++----+----------+ +| id | location | +|----+----------| ++----+----------+ + +> select * from bookmarks; ++----+----------+ +| id | location | +|----+----------| ++----+----------+ +``` + +You can force Postgres to respect the casing by wrapping the table name in +quotes. + +```sql +> create table "BookMarks" ( + id integer generated always as identity primary key, + location text not null + ); + +> \d ++--------+--------------------+----------+----------+ +| Schema | Name | Type | Owner | +|--------+--------------------+----------+----------| +| public | BookMarks | table | postgres | +| public | BookMarks_id_seq | sequence | postgres | ++--------+--------------------+----------+----------+ + +> select * from "BookMarks"; ++----+----------+ +| id | location | +|----+----------| ++----+----------+ + +> select * from "bookmarks"; +relation "bookmarks" does not exist +LINE 1: select * from "bookmarks" + ^ + +> select * from BookMarks; +relation "bookmarks" does not exist +LINE 1: select * from BookMarks + ^ +``` + +That then means you have to quote your table name anytime you want to refer to +it in a query. It's not worth it. It is better to always keep your table names +lower-case using snake case. + +[source](https://weiyen.net/articles/avoid-capital-letters-in-postgres-names)