From d7d331b688d9f10b51b5564725bbca4eb471d18f Mon Sep 17 00:00:00 2001 From: jbranchaud Date: Mon, 21 Oct 2024 11:04:04 -0500 Subject: [PATCH] Add Put Unique Constraint On Generated Column as a Postgres TIL --- README.md | 3 +- ...t-unique-constraint-on-generated-column.md | 46 +++++++++++++++++++ 2 files changed, 48 insertions(+), 1 deletion(-) create mode 100644 postgres/put-unique-constraint-on-generated-column.md diff --git a/README.md b/README.md index 422dba0..d2146ba 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). -_1477 TILs and counting..._ +_1478 TILs and counting..._ --- @@ -804,6 +804,7 @@ _1477 TILs and counting..._ - [Pretty Printing JSONB Rows](postgres/pretty-printing-jsonb-rows.md) - [Prevent A Query From Running Too Long](postgres/prevent-a-query-from-running-too-long.md) - [Print The Query Buffer In psql](postgres/print-the-query-buffer-in-psql.md) +- [Put Unique Constraint On Generated Column](postgres/put-unique-constraint-on-generated-column.md) - [Remove Not Null Constraint From A Column](postgres/remove-not-null-constraint-from-a-column.md) - [Renaming A Sequence](postgres/renaming-a-sequence.md) - [Renaming A Table](postgres/renaming-a-table.md) diff --git a/postgres/put-unique-constraint-on-generated-column.md b/postgres/put-unique-constraint-on-generated-column.md new file mode 100644 index 0000000..e40d0dc --- /dev/null +++ b/postgres/put-unique-constraint-on-generated-column.md @@ -0,0 +1,46 @@ +# Put Unique Constraint On Generated Column + +You cannot apply a _unique constraint_ to an expression over a column, e.g. +`lower(email)`. You can, however, create a [generated +column](https://www.postgresql.org/docs/current/ddl-generated-columns.html) for +that expression and then apply the unique constraint to that generated column. + +Here is what that could look like: + +```sql +> create table users ( + id integer generated always as identity primary key, + name text not null, + email text not null, + email_lower text generated always as (lower(email)) stored, + unique ( email_lower ) +); + +> \d users ++-------------+---------+-----------------------------------------------------------------+ +| Column | Type | Modifiers | +|-------------+---------+-----------------------------------------------------------------| +| id | integer | not null generated always as identity | +| name | text | not null | +| email | text | not null | +| email_lower | text | default lower(email) generated always as (lower(email)) stored | ++-------------+---------+-----------------------------------------------------------------+ +Indexes: + "users_pkey" PRIMARY KEY, btree (id) + "users_email_lower_key" UNIQUE CONSTRAINT, btree (email_lower) +``` + +And then an demonstration of violating that constraint: + +```sql + +> insert into users (name, email) values ('Bob', 'bob@email.com'); +INSERT 0 1 + +> insert into users (name, email) values ('Bobby', 'BOB@email.com'); +duplicate key value violates unique constraint "users_email_lower_key" +DETAIL: Key (email_lower)=(bob@email.com) already exists. +``` + +The main tradeoff here is that you are doubling the amount of storage you need +for that column. Unless it is a massive table, that is likely not an issue.