From aaa0edee981d530fe8c164f30868a9672b7a9ff4 Mon Sep 17 00:00:00 2001 From: jbranchaud Date: Wed, 9 Aug 2023 16:46:16 -0500 Subject: [PATCH] Add Change The Owner Of A Sequence as a Postgres TIL --- README.md | 3 +- postgres/change-the-owner-of-a-sequence.md | 32 ++++++++++++++++++++++ 2 files changed, 34 insertions(+), 1 deletion(-) create mode 100644 postgres/change-the-owner-of-a-sequence.md diff --git a/README.md b/README.md index a5247d3..f4c3cbf 100644 --- a/README.md +++ b/README.md @@ -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). -_1329 TILs and counting..._ +_1330 TILs and counting..._ --- @@ -613,6 +613,7 @@ _1329 TILs and counting..._ - [Between Symmetric](postgres/between-symmetric.md) - [Capitalize All The Words](postgres/capitalize-all-the-words.md) - [Change The Current Directory For psql](postgres/change-the-current-directory-for-psql.md) +- [Change The Owner Of A Sequence](postgres/change-the-owner-of-a-sequence.md) - [Check If The Local Server Is Running](postgres/check-if-the-local-server-is-running.md) - [Check If User Role Exists For Database](postgres/check-if-user-role-exists-for-database.md) - [Check Table For Any Oprhaned Records](postgres/check-table-for-any-orphaned-records.md) diff --git a/postgres/change-the-owner-of-a-sequence.md b/postgres/change-the-owner-of-a-sequence.md new file mode 100644 index 0000000..89ee754 --- /dev/null +++ b/postgres/change-the-owner-of-a-sequence.md @@ -0,0 +1,32 @@ +# Change The Owner Of A Sequence + +Sequence ownership is one of those things in PostgreSQL that is just under the +surface and so it is easy to not know about it. If, however, you are doing a +live migration where you are swapping out a column or entire table, you'll need +to know about it. + +For instance, consider migrating a primary key column from `int` to `bigint`. +Let's say you construct and backfill the new `bigint` column and then swap it +out with the `int` column. + +Run a sequence ownership query like [the ones discussed in this +article](https://sadique.io/blog/2019/05/07/viewing-sequence-ownership-information-in-postgres/) +and you'll see that the original `int` column still owns the sequence. + +If you try to drop `old_id`, you'll fortunately get a warning from Postgres: + +```sql +alter table cats drop column old_id; +ERROR: cannot drop column old_id of table cats because other objects depend on it +DETAIL: default value for column id of table cats depends on sequence cats_id_seq +HINT: Use DROP ... CASCADE to drop the dependent objects too. +``` + +The `DROP ... CASCADE` suggestion is not the thing to do here. Instead, you'll +want to update the ownership of the sequence to the _new_ `id` column: + +```sql +alter sequence cats_id_seq owned by cats.id; +``` + +[source](https://www.postgresql.org/docs/current/sql-altersequence.html)