mirror of
https://github.com/jbranchaud/til
synced 2026-01-04 23:58:01 +00:00
Add Add Unique Constraint Using Existing Index 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).
|
||||||
|
|
||||||
_1484 TILs and counting..._
|
_1485 TILs and counting..._
|
||||||
|
|
||||||
---
|
---
|
||||||
|
|
||||||
@@ -703,6 +703,7 @@ _1484 TILs and counting..._
|
|||||||
- [A Better Null Display Character](postgres/a-better-null-display-character.md)
|
- [A Better Null Display Character](postgres/a-better-null-display-character.md)
|
||||||
- [Add Foreign Key Constraint Without A Full Lock](postgres/add-foreign-key-constraint-without-a-full-lock.md)
|
- [Add Foreign Key Constraint Without A Full Lock](postgres/add-foreign-key-constraint-without-a-full-lock.md)
|
||||||
- [Add ON DELETE CASCADE To Foreign Key Constraint](postgres/add-on-delete-cascade-to-foreign-key-constraint.md)
|
- [Add ON DELETE CASCADE To Foreign Key Constraint](postgres/add-on-delete-cascade-to-foreign-key-constraint.md)
|
||||||
|
- [Add Unique Constraint Using Existing Index](postgres/add-unique-constraint-using-existing-index.md)
|
||||||
- [Adding Composite Uniqueness Constraints](postgres/adding-composite-uniqueness-constraints.md)
|
- [Adding Composite Uniqueness Constraints](postgres/adding-composite-uniqueness-constraints.md)
|
||||||
- [Aggregate A Column Into An Array](postgres/aggregate-a-column-into-an-array.md)
|
- [Aggregate A Column Into An Array](postgres/aggregate-a-column-into-an-array.md)
|
||||||
- [Assumed Radius Of The Earth](postgres/assumed-radius-of-the-earth.md)
|
- [Assumed Radius Of The Earth](postgres/assumed-radius-of-the-earth.md)
|
||||||
|
|||||||
25
postgres/add-unique-constraint-using-existing-index.md
Normal file
25
postgres/add-unique-constraint-using-existing-index.md
Normal file
@@ -0,0 +1,25 @@
|
|||||||
|
# Add Unique Constraint Using Existing Index
|
||||||
|
|
||||||
|
Adding a unique constraint to an existing column on a production table can
|
||||||
|
block updates. If we need to avoid this kind of locking for the duration of
|
||||||
|
index creation, then we can first create the index concurrently and then use
|
||||||
|
that existing index to back the unique constraint.
|
||||||
|
|
||||||
|
```sql
|
||||||
|
create index concurrently users_email_idx on users (email);
|
||||||
|
|
||||||
|
-- wait for that to complete
|
||||||
|
|
||||||
|
alter table users
|
||||||
|
add constraint unique_users_email unique using index users_email_idx;
|
||||||
|
```
|
||||||
|
|
||||||
|
First, we concurrently create the index. The time this takes will depend on how
|
||||||
|
large the table is. That's the blocking time we are avoiding with this
|
||||||
|
approach. Then once that completes we can apply a unique constraint using that
|
||||||
|
preexisting index.
|
||||||
|
|
||||||
|
Note: if a non-unique value exists in the table for that column, adding the
|
||||||
|
constraint will fail. You'll need to deal with that _duplicate_ value first.
|
||||||
|
|
||||||
|
[source](https://dba.stackexchange.com/questions/81627/postgresql-9-3-add-unique-constraint-using-an-existing-unique-index)
|
||||||
Reference in New Issue
Block a user