Skip to content

Instantly share code, notes, and snippets.

@SkylerLipthay
Last active May 29, 2024 10:55
Show Gist options
  • Save SkylerLipthay/b87ad42408f5a110615be4677ab60e3f to your computer and use it in GitHub Desktop.
Save SkylerLipthay/b87ad42408f5a110615be4677ab60e3f to your computer and use it in GitHub Desktop.
Prevent self-referential foreign key cycles in PostgreSQL

This migration creates a trigger function prevent_cycle to be used to prevent foreign key cycles in self-referential tables.

The first argument of the trigger function is the table's name; the second argument is the table's self-referential foreign key column.

Currently, it is assumed that the table has the column id, though this could easily be change.

Example

CREATE TABLE hierarchy (
  id BIGSERIAL PRIMARY KEY,
  parent_id BIGINT REFERENCES hierarchy(id)
);

CREATE TRIGGER prevent_hierarchy_cycle
  AFTER INSERT OR UPDATE OF parent_id ON hierarchy
  FOR EACH ROW
  EXECUTE PROCEDURE prevent_cycle('hierarchy', 'parent_id');
INSERT INTO hierarchy (id, parent_id) VALUES (1, NULL);
INSERT INTO hierarchy (id, parent_id) VALUES (2, 1);
UPDATE hierarchy SET parent_id = 2 WHERE id = 1; -- Exception raised!
DROP FUNCTION prevent_cycle();
This is free and unencumbered software released into the public domain.
Anyone is free to copy, modify, publish, use, compile, sell, or
distribute this software, either in source code form or as a compiled
binary, for any purpose, commercial or non-commercial, and by any
means.
In jurisdictions that recognize copyright laws, the author or authors
of this software dedicate any and all copyright interest in the
software to the public domain. We make this dedication for the benefit
of the public at large and to the detriment of our heirs and
successors. We intend this dedication to be an overt act of
relinquishment in perpetuity of all present and future rights to this
software under copyright law.
THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND,
EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF
MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT.
IN NO EVENT SHALL THE AUTHORS BE LIABLE FOR ANY CLAIM, DAMAGES OR
OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE,
ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR
OTHER DEALINGS IN THE SOFTWARE.
For more information, please refer to <https://unlicense.org>
CREATE FUNCTION prevent_cycle()
RETURNS TRIGGER AS $$
DECLARE
rc INTEGER;
BEGIN
EXECUTE format(
'WITH RECURSIVE search_graph(%2$I, path, cycle) AS (' ||
'SELECT t.%2$I, ARRAY[t.id, t.%2$I], (t.id = t.%2$I) ' ||
'FROM %1$I t ' ||
'WHERE t.id = $1 ' ||
'UNION ALL ' ||
'SELECT t.%2$I, sg.path || t.%2$I, t.%2$I = ANY(sg.path) ' ||
'FROM search_graph sg ' ||
'JOIN %1$I t on t.id = sg.%2$I ' ||
'WHERE NOT sg.cycle' ||
') SELECT 1 FROM search_graph WHERE cycle LIMIT 1;',
TG_ARGV[0], TG_ARGV[1]) USING NEW.id;
GET DIAGNOSTICS rc = ROW_COUNT;
IF rc > 0 THEN
RAISE EXCEPTION 'Self-referential foreign key cycle detected';
ELSE
RETURN NEW;
END IF;
END
$$ LANGUAGE plpgsql;
@mehdisadeghi
Copy link

Hi @SkylerLipthay! Your trigger works like charm. Have you decided for a license by any chance?

@SkylerLipthay
Copy link
Author

Sure, I added license text to this Gist. It's public domain. Glad it helped you!

@mehdisadeghi
Copy link

Thank you!

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment