Skip to content

Instantly share code, notes, and snippets.

@dineshmm23
Last active February 9, 2018 07:12
Show Gist options
  • Save dineshmm23/7482ddc14c44af71897db9a42883ec4d to your computer and use it in GitHub Desktop.
Save dineshmm23/7482ddc14c44af71897db9a42883ec4d to your computer and use it in GitHub Desktop.
--Be aware: this function won't copy attributes of initial foreign key.
--It only takes foreign table name / column name, drops current key and replaces with new one.
CREATE OR REPLACE FUNCTION
replace_foreign_key(f_table VARCHAR, f_column VARCHAR, new_options VARCHAR)
RETURNS VARCHAR
AS $$
DECLARE constraint_name varchar;
DECLARE reftable varchar;
DECLARE refcolumn varchar;
BEGIN
SELECT tc.constraint_name, ccu.table_name AS foreign_table_name, ccu.column_name AS foreign_column_name
FROM
information_schema.table_constraints AS tc
JOIN information_schema.key_column_usage AS kcu
ON tc.constraint_name = kcu.constraint_name
JOIN information_schema.constraint_column_usage AS ccu
ON ccu.constraint_name = tc.constraint_name
WHERE constraint_type = 'FOREIGN KEY'
AND tc.table_name= f_table AND kcu.column_name= f_column
INTO constraint_name, reftable, refcolumn;
EXECUTE 'alter table ' || f_table || ' drop constraint ' || constraint_name ||
', ADD CONSTRAINT ' || constraint_name || ' FOREIGN KEY (' || f_column || ') ' ||
' REFERENCES ' || reftable || '(' || refcolumn || ') ' || new_options || ';';
RETURN 'Constraint replaced: ' || constraint_name || ' (' || f_table || '.' || f_column ||
' -> ' || reftable || '.' || refcolumn || '); New options: ' || new_options;
END;
$$ LANGUAGE plpgsql;
--https://stackoverflow.com/a/32920837
--credits to Dan Key
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment