mirror of
https://github.com/jbranchaud/til
synced 2026-01-05 08:08:02 +00:00
Add Put Unique Constraint On Generated Column 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).
|
||||||
|
|
||||||
_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)
|
- [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)
|
- [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)
|
- [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)
|
- [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 Sequence](postgres/renaming-a-sequence.md)
|
||||||
- [Renaming A Table](postgres/renaming-a-table.md)
|
- [Renaming A Table](postgres/renaming-a-table.md)
|
||||||
|
|||||||
46
postgres/put-unique-constraint-on-generated-column.md
Normal file
46
postgres/put-unique-constraint-on-generated-column.md
Normal file
@@ -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.
|
||||||
Reference in New Issue
Block a user