mirror of
https://github.com/jbranchaud/til
synced 2026-01-05 08:08:02 +00:00
Add Enforce Uniqueness On Column Expression as a Postgres TIL
This commit is contained in:
@@ -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).
|
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)
|
- [Duplicate A Local Database](postgres/duplicate-a-local-database.md)
|
||||||
- [Edit Existing Functions](postgres/edit-existing-functions.md)
|
- [Edit Existing Functions](postgres/edit-existing-functions.md)
|
||||||
- [Enable Logging Of Database Activity](postgres/enable-logging-of-database-activity.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 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)
|
- [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)
|
- [Export Query Results To A CSV](postgres/export-query-results-to-a-csv.md)
|
||||||
|
|||||||
35
postgres/enforce-uniqueness-on-column-expression.md
Normal file
35
postgres/enforce-uniqueness-on-column-expression.md
Normal file
@@ -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.
|
||||||
Reference in New Issue
Block a user