Introduced a SQL script with accompanying documentation that corrects sequence values in PostgreSQL databases following data import. The script dynamically adjusts sequence numbers to align with the maximum values present in their respective tables, addressing issues that can occur when sequences fall out of sync after bulk inserts or imports. Use caution as provided without warranty.
33 lines
1.2 KiB
SQL
33 lines
1.2 KiB
SQL
DO $$
|
|
DECLARE
|
|
rec record;
|
|
v_max_value bigint;
|
|
v_sequence_name text;
|
|
v_last_value bigint;
|
|
BEGIN
|
|
FOR rec IN SELECT column_default, table_name, column_name
|
|
FROM information_schema.columns
|
|
WHERE column_default LIKE 'nextval(%' AND table_schema = 'public'
|
|
LOOP
|
|
v_sequence_name := substring(rec.column_default from '''(.+?)''');
|
|
|
|
-- Get current maximum value in the relevant column
|
|
EXECUTE FORMAT('SELECT MAX(%I) FROM %I', rec.column_name, rec.table_name) INTO v_max_value;
|
|
|
|
-- Default max value to 0 if no rows present
|
|
IF v_max_value IS NULL THEN
|
|
v_max_value := 0;
|
|
END IF;
|
|
|
|
-- Get the last value from the sequence
|
|
EXECUTE FORMAT('SELECT last_value FROM %I', v_sequence_name) INTO v_last_value;
|
|
|
|
-- Compare and set the new sequence value if needed
|
|
IF v_last_value < v_max_value THEN
|
|
PERFORM setval(v_sequence_name, v_max_value, false);
|
|
RAISE NOTICE 'Sequence "%" has been set to %', v_sequence_name, v_max_value;
|
|
ELSE
|
|
RAISE NOTICE 'Sequence "%" is already ahead with a last value of %', v_sequence_name, v_last_value;
|
|
END IF;
|
|
END LOOP;
|
|
END$$;
|