|
| 1 | +# Put Unique Constraint On Generated Column |
| 2 | + |
| 3 | +You cannot apply a _unique constraint_ to an expression over a column, e.g. |
| 4 | +`lower(email)`. You can, however, create a [generated |
| 5 | +column](https://www.postgresql.org/docs/current/ddl-generated-columns.html) for |
| 6 | +that expression and then apply the unique constraint to that generated column. |
| 7 | + |
| 8 | +Here is what that could look like: |
| 9 | + |
| 10 | +```sql |
| 11 | +> create table users ( |
| 12 | + id integer generated always as identity primary key, |
| 13 | + name text not null, |
| 14 | + email text not null, |
| 15 | + email_lower text generated always as (lower(email)) stored, |
| 16 | + unique ( email_lower ) |
| 17 | +); |
| 18 | + |
| 19 | +> \d users |
| 20 | ++-------------+---------+-----------------------------------------------------------------+ |
| 21 | +| Column | Type | Modifiers | |
| 22 | +|-------------+---------+-----------------------------------------------------------------| |
| 23 | +| id | integer | not null generated always as identity | |
| 24 | +| name | text | not null | |
| 25 | +| email | text | not null | |
| 26 | +| email_lower | text | default lower(email) generated always as (lower(email)) stored | |
| 27 | ++-------------+---------+-----------------------------------------------------------------+ |
| 28 | +Indexes: |
| 29 | + "users_pkey" PRIMARY KEY, btree (id) |
| 30 | + "users_email_lower_key" UNIQUE CONSTRAINT, btree (email_lower) |
| 31 | +``` |
| 32 | + |
| 33 | +And then an demonstration of violating that constraint: |
| 34 | + |
| 35 | +```sql |
| 36 | + |
| 37 | +> insert into users (name, email) values ( 'Bob', '[email protected]'); |
| 38 | +INSERT 0 1 |
| 39 | + |
| 40 | +> insert into users (name, email) values ( 'Bobby', '[email protected]'); |
| 41 | +duplicate key value violates unique constraint "users_email_lower_key" |
| 42 | +DETAIL: Key (email_lower)=(bob@email.com) already exists. |
| 43 | +``` |
| 44 | + |
| 45 | +The main tradeoff here is that you are doubling the amount of storage you need |
| 46 | +for that column. Unless it is a massive table, that is likely not an issue. |
0 commit comments