Skip to content

Instantly share code, notes, and snippets.

@stellingsimon
Last active August 26, 2020 12:04
Show Gist options
  • Save stellingsimon/011478d1e74298137fbfe733fb2b3e4b to your computer and use it in GitHub Desktop.
Save stellingsimon/011478d1e74298137fbfe733fb2b3e4b to your computer and use it in GitHub Desktop.
mock FK dependencies that are in safe distance
-- Example usage:
-- ==============
--
-- (first, see http://www.jooq.org/sakila for an overview of the Sakila DB schema)
--
-- Assuming you are writing a test for 'returnRentalAndPayImmediately()':
--
-- Then, tables under test are 'rental' and 'payment'.
-- You want to keep the FKs between the following tables, since they may point you to crucial bugs:
-- payment, rental, staff, customer, inventory
--
-- You want to drop these FKs to avoid creating entities unrelated to your test:
-- * from 'staff' to 'store' and 'address'
-- * from 'customer' to 'store' and 'address'
-- * from 'inventory' to 'film' and 'store'
--
-- The following will do this automatically for you:
-- SELECT mock_fk_dependencies('public', 'rental', 'payment');
------------------------------------------------------------------------------------------------------------------------
-- global helper functions -
------------------------------------------------------------------------------------------------------------------------
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
------------------------------------------------------------------------------------------------------------------------
-- global helper functions -
------------------------------------------------------------------------------------------------------------------------
DROP FUNCTION IF EXISTS global.drop_foreign_key_constraint( VARCHAR(64), VARCHAR(64), VARCHAR(64) );
CREATE OR REPLACE FUNCTION global.drop_foreign_key_constraint(
_schema_name VARCHAR(64),
_table_name VARCHAR(64),
_fk_name VARCHAR(64))
RETURNS VOID
AS
$$
DECLARE
column_name varchar = (
SELECT kcu.column_name
FROM information_schema.table_constraints AS tc
JOIN information_schema.key_column_usage AS kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema
WHERE tc.constraint_type = 'FOREIGN KEY'
AND tc.table_schema = _schema_name
AND tc.table_name = _table_name
AND tc.constraint_name = _fk_name
);
BEGIN
EXECUTE 'ALTER TABLE "' || _schema_name || '"."' || _table_name || '" DROP CONSTRAINT "' || _fk_name || '"';
EXECUTE 'ALTER TABLE "' || _schema_name || '"."' || _table_name || '" ALTER COLUMN "' || column_name || '" DROP NOT NULL';
END
$$
LANGUAGE plpgsql;
DROP FUNCTION IF EXISTS global.drop_foreign_key_constraint_by_oid( OID, VARCHAR(64) );
CREATE OR REPLACE FUNCTION global.drop_foreign_key_constraint_by_oid(
_table_oid OID,
_fk_name VARCHAR(64))
RETURNS VOID
AS
$$
DECLARE
schema_name VARCHAR(64);
table_name VARCHAR(64);
BEGIN
SELECT
INTO schema_name, table_name
nsp.nspname,
tbl.relname
FROM pg_namespace nsp
JOIN pg_class tbl ON nsp.oid = tbl.relnamespace
WHERE tbl.oid = _table_oid;
PERFORM global.drop_foreign_key_constraint(schema_name, table_name, _fk_name);
END
$$
LANGUAGE plpgsql;
DROP FUNCTION IF EXISTS global.outbound_foreign_key_constraints(table_oids OID [] );
CREATE OR REPLACE FUNCTION global.outbound_foreign_key_constraints(
_table_oids OID []
)
RETURNS TABLE(
fk_source_table OID,
fk_target_table OID,
fk_name VARCHAR(64)
)
AS
$$
SELECT
conrelid :: OID AS fk_source_table,
confrelid :: OID AS fk_target_table,
conname :: TEXT AS fk_name
FROM pg_constraint c
WHERE contype = 'f' -- FK constraint
AND conrelid = ANY (_table_oids) -- from inside the set of given tables
ORDER BY conrelid :: REGCLASS :: TEXT;
$$
STABLE
LANGUAGE SQL;
DROP FUNCTION IF EXISTS global.direct_dependencies(OID []);
CREATE OR REPLACE FUNCTION global.direct_dependencies(_table_oids OID [])
RETURNS TABLE(
"table" OID
)
AS
$$
SELECT
confrelid :: OID AS fk_target_table
FROM pg_constraint c
WHERE contype = 'f' -- FK constraint
AND conrelid = ANY (_table_oids) -- from inside the set of given tables
AND NOT confrelid = ANY (_table_oids) -- to outside the set of given tables
ORDER BY conrelid :: REGCLASS :: TEXT;
$$
STABLE
LANGUAGE SQL;
DROP FUNCTION IF EXISTS global.mock_fk_dependencies( VARCHAR(64), VARCHAR(64) [] );
CREATE OR REPLACE FUNCTION global.mock_fk_dependencies(
_schema_name VARCHAR(64),
_tables_under_test VARCHAR(64) []
)
RETURNS VOID
AS
$$
DECLARE
oids_of_tables_under_test OID [] = ARRAY(SELECT ('"' || _schema_name || '"."' || unnest(_tables_under_test) || '"') :: REGCLASS :: OID);
oids_of_direct_dependencies OID [] = ARRAY(SELECT global.direct_dependencies(oids_of_tables_under_test));
BEGIN
PERFORM global.drop_foreign_key_constraint_by_oid(fk_source_table, fk_name)
FROM global.outbound_foreign_key_constraints(oids_of_direct_dependencies);
END
$$
LANGUAGE PLPGSQL;
CREATE OR REPLACE FUNCTION global.debug_mock_fk_dependencies(
_schema_name VARCHAR(64),
_tables_under_test VARCHAR(64) []
)
RETURNS TABLE(
fk_source_table OID,
fk_target_table OID,
fk_name VARCHAR(64)
)
AS
$$
DECLARE
oids_of_tables_under_test OID [] = ARRAY(SELECT ('"' || _schema_name || '"."' || unnest(_tables_under_test) || '"') :: REGCLASS :: OID);
oids_of_direct_dependencies OID [] = ARRAY(SELECT global.direct_dependencies(oids_of_tables_under_test));
BEGIN
RETURN QUERY (SELECT * FROM global.outbound_foreign_key_constraints(oids_of_direct_dependencies));
END
$$
LANGUAGE PLPGSQL;
-- select * from global.debug_mock_fk_dependencies('schema', '{table1,table2}'::varchar[]);
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment