From 4a72c63e4260b4b0e4a4a0fb08816ac970979e05 Mon Sep 17 00:00:00 2001 From: jbranchaud Date: Sat, 19 Oct 2024 19:13:30 -0500 Subject: [PATCH] Add Enforce Uniqueness On Column Expression as a Postgres TIL --- README.md | 3 +- ...enforce-uniqueness-on-column-expression.md | 35 +++++++++++++++++++ 2 files changed, 37 insertions(+), 1 deletion(-) create mode 100644 postgres/enforce-uniqueness-on-column-expression.md diff --git a/README.md b/README.md index 40d8576..1d359b3 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). -_1475 TILs and counting..._ +_1476 TILs and counting..._ --- @@ -744,6 +744,7 @@ _1475 TILs and counting..._ - [Duplicate A Local Database](postgres/duplicate-a-local-database.md) - [Edit Existing Functions](postgres/edit-existing-functions.md) - [Enable Logging Of Database Activity](postgres/enable-logging-of-database-activity.md) +- [Enforce Uniqueness On Column Expression](postgres/enforce-uniqueness-on-column-expression.md) - [Escaping A Quote In A String](postgres/escaping-a-quote-in-a-string.md) - [Escaping String Literals With Dollar Quoting](postgres/escaping-string-literals-with-dollar-quoting.md) - [Export Query Results To A CSV](postgres/export-query-results-to-a-csv.md) diff --git a/postgres/enforce-uniqueness-on-column-expression.md b/postgres/enforce-uniqueness-on-column-expression.md new file mode 100644 index 0000000..ee756da --- /dev/null +++ b/postgres/enforce-uniqueness-on-column-expression.md @@ -0,0 +1,35 @@ +# Enforce Uniqueness On Column Expression + +When creating a table for, say `users`, where you will store `email` addresses, +you'll likely want to enforce uniqueness on the that `email` field. And because +people have all sorts of ways of entering their emails, in terms of casing, you +may be tempted to try to enforce uniqueness on a lowercased version of `email`. + +```sql +create table users ( + id integer generated always as identity primary key, + email text not null, + unique ( lower(email) ) -- !! this won't work +); +``` + +A unique _constraint_ must be on one or more columns. You cannot include an +_expression_ when defining the unique constraint. + +You can however accomplish similar aims with [a _unique index_ on the +expression](https://www.postgresql.org/docs/current/indexes-expressional.html). +That is because the index is able to store the result of the expression in +itself. + +```sql +create table users ( + id integer generated always as identity primary key, + email text not null +); + +create unique index unq_lower_email on users ( lower(email) ); +``` + +This is likely what you want for this example anyway because it will probably +be a common query to look up the user by `lower(email)` and the index will +speed up those queries.