Last active
September 12, 2024 16:40
-
-
Save MarkusH/4c03d0867ba37b6b89379bced12cb3ae to your computer and use it in GitHub Desktop.
A script that outputs the raw SQL to convert Django's serial columns to identity columns.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
WITH tab AS ( | |
SELECT | |
a.attrelid::regclass::text AS t, | |
a.attname AS c, | |
pg_get_serial_sequence(a.attrelid::regclass::text, a.attname) AS s, | |
nextval(pg_get_serial_sequence(a.attrelid::regclass::text, a.attname)) AS v | |
FROM pg_attribute a | |
JOIN pg_class c ON c.oid = a.attrelid | |
WHERE | |
a.attrelid::regclass::text LIKE '%' | |
AND c.relkind IN ('r', 'p') /* regular and partitioned tables */ | |
AND a.attnum > 0 | |
AND NOT a.attisdropped | |
AND a.atttypid = ANY ('{int,int8,int2}'::regtype[]) | |
AND EXISTS ( | |
SELECT FROM pg_attrdef ad | |
WHERE | |
ad.adrelid = a.attrelid | |
AND ad.adnum = a.attnum | |
AND ( | |
pg_get_expr(ad.adbin, ad.adrelid) | |
= | |
'nextval(''' | |
|| ( | |
pg_get_serial_sequence(a.attrelid::regclass::text, a.attname) | |
)::regclass | |
|| '''::regclass)' | |
) | |
) | |
ORDER BY a.attnum | |
) | |
SELECT | |
'BEGIN; ' | |
|| 'LOCK TABLE ' || quote_ident(t) || ' IN ACCESS EXCLUSIVE MODE; ' | |
|| 'ALTER TABLE ' || quote_ident(t) || ' ALTER COLUMN ' || quote_ident(c) || ' DROP DEFAULT; ' | |
|| 'DROP SEQUENCE ' || s || '; ' | |
|| 'ALTER TABLE ' || quote_ident(t) || ' ALTER ' || quote_ident(c) || ' ADD GENERATED BY DEFAULT AS IDENTITY (RESTART ' || v || '); ' | |
|| 'COMMIT;' | |
FROM tab; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment
Unless I'm mistaken, this appears to get the
nextval
of the old sequence at the the SQL is generated, rather than at the time the generated SQL itself it run. That means that if any rows are inserted in-between the time the SQL is generated and when it's run, the new sequence value will be incorrect. Shouldn't the call tonextval
be part of the generated SQL (and inside the exclusive table lock)? That'd also mean re-ordering commands so that theDROP SEQUENCE
statement is after the lastALTER TABLE
.Update: Here's an updated version of this script that fixes the issue w/ nextval timing.
As well, here's an example bash script of how you can generate and run the migration code on a batch of DBs: