1
0
mirror of https://github.com/jbranchaud/til synced 2026-01-02 22:58:01 +00:00

Add Change The Owner Of A Sequence as a Postgres TIL

This commit is contained in:
jbranchaud
2023-08-09 16:46:16 -05:00
parent 67e8996f99
commit aaa0edee98
2 changed files with 34 additions and 1 deletions

View File

@@ -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)

View File

@@ -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)