diff --git a/README.md b/README.md index d740450..6da4c7f 100644 --- a/README.md +++ b/README.md @@ -9,7 +9,7 @@ and pairing with smart people at Hashrocket. For a steady stream of TILs, [sign up for my newsletter](https://tinyletter.com/jbranchaud). -_862 TILs and counting..._ +_863 TILs and counting..._ --- @@ -383,6 +383,7 @@ _862 TILs and counting..._ ### PostgreSQL - [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 ON DELETE CASCADE To Foreign Key Constraint](postgres/add-on-delete-cascade-to-foreign-key-constraint.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) diff --git a/postgres/add-foreign-key-constraint-without-a-full-lock.md b/postgres/add-foreign-key-constraint-without-a-full-lock.md new file mode 100644 index 0000000..8949667 --- /dev/null +++ b/postgres/add-foreign-key-constraint-without-a-full-lock.md @@ -0,0 +1,31 @@ +# Add Foreign Key Constraint Without A Full Lock + +Adding a foreign key constraint to a large production table can cause a full +table lock resulting in downtime. This is because the entire table needs to be +scanned to check that the constraint is valid. + +The amount of locking, and ultimately the impact on your app, can be reduced by +spreading this action across two commands. First is to add the constraint +without checking that all the existing records are valid. + +```sql +alter table books + add constraint fk_books_authors + foreign key (author_id) + references authors(id) + not valid; +``` + +The constraint will be added immediately and any subsequent inserts or updates +will be subject to the new foreign key constraint. + +The second step is to make this constraint valid for all the existing rows. + +```sql +alter table books validate constraint fk_books_authors; +``` + +This "validation acquires only a SHARE UPDATE EXCLUSIVE lock on the table being +altered." This is lower impact than a full table lock. + +[Source](https://www.postgresql.org/docs/current/sql-altertable.html#SQL-ALTERTABLE-NOTES)