diff --git a/examples/mocking_and_faking.sql b/examples/mocking_and_faking.sql new file mode 100644 index 00000000..9dd38376 --- /dev/null +++ b/examples/mocking_and_faking.sql @@ -0,0 +1,359 @@ +/* +DROP EXTENSION pgtap; + +CREATE EXTENSION pgtap schema tap; +*/ + +create schema if not exists tap; +create schema if not exists pgconf; +create schema if not exists tests; + +set search_path to public, tap, pgconf; +set track_functions = 'all' ; + +drop function if exists pgconf.get_osv_slice(int, int, int); +drop function if exists pgconf.get_tree_of(int); +drop function if exists pgconf.time_machine_now(); +drop procedure if exists pgconf.make_osv_report(); +drop procedure if exists tests.create_test_data(); +drop function if exists tests.test_osv_on_time(); +drop function if exists tests.test_osv_not_on_time(); +drop function if exists tests.test_get_tree_of_called_times(); + +drop table if exists pgconf.osv; +drop table if exists pgconf.transactions; +drop table if exists pgconf.analytic; +drop table if exists pgconf.account; + +create table pgconf.account( + id int generated always as identity primary key + , parent_id int + , num text + , constraint account_01_fk foreign key(parent_id) references pgconf.account(id) +); + +create table pgconf.analytic( + id int generated always as identity primary key + , subconto text +); + +create table pgconf.transactions( + account_num text + , subconto_1 text + , subconto_2 text + , subconto_3 text + , amount_dt numeric(15, 2) + , amount_ct numeric(15, 2) +); + +create table pgconf.osv( + account_id int + , subconto_1_id int + , subconto_2_id int + , subconto_3_id int + , amount_dt numeric(15, 2) + , amount_ct numeric(15, 2) + , constraint osv_01_fk foreign key(account_id) references pgconf.account(id) + , constraint osv_02_fk foreign key(subconto_1_id) references pgconf.analytic(id) + , constraint osv_03_fk foreign key(subconto_2_id) references pgconf.analytic(id) + , constraint osv_04_fk foreign key(subconto_3_id) references pgconf.analytic(id) +); + +create or replace function pgconf.get_osv_slice(_account_id int, _subc_1 int, _subc_2 int) +returns table( + ordercol text[] + , account_num text + , subconto_1_id int + , subconto_1 text + , subconto_2_id int + , subconto_2 text + , subconto_3 text + , amount_dt numeric(15, 2) + , amount_ct numeric(15, 2) +) +language plpgsql +as $$ +begin +return query +with recursive account_tree as ( + select id, parent_id, num + from pgconf.account + where (id = _account_id or _account_id is null) + and parent_id is null + union all + select a.id, a.parent_id, a.num + from account_tree t + join pgconf.account a + on a.parent_id = t.id +)search depth first by num set account_order +select + t.account_order::text[] + , t.num as account_num + , a1.id as subconto_1_id + , a1.subconto as subconto_1 + , a2.id as subconto_2_id + , a2.subconto as subconto_2 + , a3.subconto as subconto_3 + , o.amount_dt + , o.amount_ct +from account_tree t +left join pgconf.osv o +on o.account_id = t.id +left join pgconf.analytic a1 +on a1.id = o.subconto_1_id +left join pgconf.analytic a2 +on a2.id = o.subconto_2_id +left join pgconf.analytic a3 +on a3.id = o.subconto_3_id +where + pgconf.time_machine_now() between '12:00'::time and '15:00'::time + and (_account_id is null and o.subconto_1_id is null and o.subconto_2_id is null and o.subconto_3_id is null) +order by t.account_order +; +end; +$$; + +create or replace function pgconf.get_tree_of(_account_id int) + returns table(id int, parent_id int, num text, lev int, is_folder bool) + language sql +as $function$ +with recursive acc as ( + select id, parent_id, num, 1 as l, True as is_folder from pgconf.account + where (id = _account_id and _account_id is not null) or (_account_id is null and parent_id is null) + union all + select a2.id, a2.parent_id, a2.num, a1.l + 1 as l + , exists(select from pgconf.account ca where ca.parent_id = a2.id) as is_folder + from acc a1 + join pgconf.account a2 + on a1.id = a2.parent_id +) +select * from acc a +$function$ +; + +create or replace function pgconf.time_machine_now() +returns time +language sql +as $$ + select now()::time; +$$; + +create or replace procedure pgconf.make_osv_report() +language plpgsql +as $$ +begin + insert into pgconf.osv(account_id, subconto_1_id, subconto_2_id, subconto_3_id, amount_dt, amount_ct) + select a.id, a1.id, a2.id, a3.id, sum(amount_dt), sum(amount_ct) + from pgconf.account a + join pgconf.transactions t + on t.account_num = a.num + left join pgconf.analytic a1 + on a1.subconto = t.subconto_1 + left join pgconf.analytic a2 + on a2.subconto = t.subconto_2 + left join pgconf.analytic a3 + on a3.subconto = t.subconto_3 + group by a.id, grouping sets( + (a.id, a1.id, a2.id, a3.id) + , (a.id, a1.id, a2.id) + , (a.id, a1.id) + , (a.id) + ); + + insert into pgconf.osv(account_id, subconto_1_id, subconto_2_id, subconto_3_id, amount_dt, amount_ct) + select + acc.id + , null, null, null + , agg.amount_dt + , agg.amount_ct + from pgconf.get_tree_of(null) as acc + left join lateral( + select + sum(osv.amount_dt) as amount_dt + , sum(osv.amount_ct) as amount_ct + from pgconf.osv + where osv.account_id in (select id from pgconf.get_tree_of(acc.id) t where not t.is_folder) + and subconto_1_id is null and subconto_2_id is null and subconto_3_id is null + ) as agg on true + where + acc.is_folder; +end; +$$; + +create or replace procedure tests.create_test_data() +language plpgsql +as $$ +begin + call tap.fake_table( + '{pgconf.account, pgconf.analytic, pgconf.osv, pgconf.transactions}'::text[], + _leave_primary_key => false, + _make_table_empty => true, + _drop_not_null => false, + _drop_collation => false + ); + + insert into pgconf.account(parent_id, num) values(null, '02'); + + insert into pgconf.account(parent_id, num) + select id, '02.01' + from pgconf.account where num = '02'; + + insert into pgconf.account(parent_id, num) values(null, '01'); + + insert into pgconf.account(parent_id, num) + select id, '03.01' + from pgconf.account where num = '01'; + + insert into pgconf.account(parent_id, num) + select id, '01.01.01' + from pgconf.account where num = '03.01'; + + insert into pgconf.account(parent_id, num) + select id, '01.01.02' + from pgconf.account where num = '03.01'; + + insert into pgconf.account(parent_id, num) + select id, '01.01.01.01' + from pgconf.account where num = '01.01.01'; + + insert into pgconf.account(parent_id, num) + select id, '01.01.01.02' + from pgconf.account where num = '01.01.01'; + + insert into pgconf.account(parent_id, num) + select id, '01.01.02.01' + from pgconf.account where num = '01.01.02'; + + insert into pgconf.analytic(subconto) values('Суб_1'), ('Суб_2'), ('Суб_3'), ('Суб_4'), ('Суб_5'), ('Суб_6'), ('Суб_7'); + + insert into pgconf.transactions(account_num, subconto_1, subconto_2, subconto_3, amount_dt, amount_ct) values + ('01.01.01.01', 'Суб_1', 'Суб_2', 'Суб_4', 10, 0) + , ('01.01.01.01', 'Суб_1', 'Суб_2', 'Суб_5', 10, 0) + , ('01.01.01.01', 'Суб_1', 'Суб_3', 'Суб_6', 10, 0) + , ('01.01.01.02', 'Суб_1', 'Суб_3', 'Суб_7', 10, 0) + , ('01.01.02.01', 'Суб_1', 'Суб_2', 'Суб_4', 10, 0) + , ('02.01', 'Суб_1', 'Суб_3', 'Суб_5', 0, 10) + , ('02.01', 'Суб_1', 'Суб_2', 'Суб_4', 0, 10); + + call pgconf.make_osv_report(); +end; +$$; + +create or replace function tests.test_osv_ordered_in_depth() +returns setof text +language plpgsql +as $$ +begin + -- GIVEN + call tests.create_test_data(); + call tap.mock_func('pgconf', 'time_machine_now', '()' + , _return_scalar_value => '13:00'::time); + + -- WHEN + perform tap.drop_prepared_statement('{expected, returned}'::text[]); + + prepare expected as + select num::text + from (values ('01', 1), ('03.01', 2), ('01.01.01', 2), ('01.01.01.01', 3), ('01.01.01.02', 4) + , ('01.01.02', 5), ('01.01.02.01', 6) + , ('02', 7), ('02.01', 8)) as t(num, id) + order by id; + + prepare returned as + select account_num from pgconf.get_osv_slice(null, null, null); + + -- THEN + return query + select tap.results_eq( + 'returned', + 'expected', + 'Accounts must be sorted in depth first.' + ); + + + create table pgconf.slice as + select * from pgconf.get_osv_slice(null, null, null); + + call tap.print_table_as_json('pgconf', 'slice'); + call tap.print_table_as_json('pgconf', 'account'); + + -- WHEN + perform tap.drop_prepared_statement('{expected, returned}'::text[]); +end; +$$; + +create or replace function tests.test_osv_on_time() +returns setof text +language plpgsql +as $$ +begin + -- GIVEN + call tests.create_test_data(); + call tap.mock_func('pgconf', 'time_machine_now', '()' + , _return_scalar_value => '15:01'::time); + + create table pgconf.x as select * from pgconf.time_machine_now(); + call tap.print_table_as_json('pgconf', 'x'); + + -- WHEN + perform tap.drop_prepared_statement('{returned}'::text[]); + + prepare returned as + select * from pgconf.get_osv_slice(null, null, null); + + -- THEN + return query + select tap.is_empty( + 'returned', + 'It is not good time to make osv report.' + ); + + perform tap.drop_prepared_statement('{returned}'::text[]); +end; +$$; + +create or replace function tests.test_osv_not_on_time() +returns setof text +language plpgsql +as $$ +begin + -- GIVEN + call tests.create_test_data(); + call tap.mock_func('pgconf', 'time_machine_now', '()' + , _return_set_value => null, _return_scalar_value => '13:00'::time); + + -- WHEN + perform tap.drop_prepared_statement('{returned}'::text[]); + + prepare returned as + select * from pgconf.get_osv_slice(null, null, null); + + -- THEN + return query + select tap.isnt_empty( + 'returned', + 'Time has come. We can make osv report.' + ); + + perform tap.drop_prepared_statement('{expected}'::text[]); +end; +$$; + +create or replace function tests.test_get_tree_of_called_times() +returns setof text +language plpgsql +as $$ +begin + -- GIVEN + call tests.create_test_data(); + + -- THEN + return query + select tap.call_count(6, 'pgconf' + , 'get_tree_of', '{int}'::name[]); +end; +$$; + +select * from tap.runtests('tests', '^test_'); + +select * from tap.runtests('tests', 'test_osv_on_time'); \ No newline at end of file diff --git a/sql/pgtap--1.3.3--1.3.4.sql b/sql/pgtap--1.3.3--1.3.4.sql index 7607e95d..f441fc81 100644 --- a/sql/pgtap--1.3.3--1.3.4.sql +++ b/sql/pgtap--1.3.3--1.3.4.sql @@ -16,6 +16,322 @@ RETURNS TEXT AS $$ ); $$ LANGUAGE SQL; +--added a column "langname" used in mock_func function +CREATE OR REPLACE VIEW tap_funky + AS SELECT p.oid AS oid, + n.nspname AS schema, + p.proname AS name, + pg_catalog.pg_get_userbyid(p.proowner) AS owner, + array_to_string(p.proargtypes::regtype[], ',') AS args, + CASE p.proretset WHEN TRUE THEN 'setof ' ELSE '' END + || p.prorettype::regtype AS returns, + p.prolang AS langoid, + p.proisstrict AS is_strict, + _prokind(p.oid) AS kind, + p.prosecdef AS is_definer, + p.proretset AS returns_set, + p.provolatile::char AS volatility, + pg_catalog.pg_function_is_visible(p.oid) AS is_visible, + l.lanname AS langname + FROM pg_catalog.pg_proc p + JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid + LEFT JOIN pg_language l ON l.oid = p.prolang +; + +--this procedure creates a mock in place of a real function +create or replace procedure mock_func( + _func_schema text + , _func_name text + , _func_args text + , _return_set_value text default null + , _return_scalar_value anyelement default null::text +) +--creates a mock in place of a real function + LANGUAGE plpgsql +AS $procedure$ +declare + _mock_ddl text; + _func_result_type text; + _func_qualified_name text; + _func_language text; + _returns_set bool; +begin + select "returns", langname, returns_set + into _func_result_type, _func_language, _returns_set + from tap_funky + where "schema" = _func_schema + and "name" = _func_name; + + if _func_language = 'sql' and _returns_set then + _mock_ddl = ' + create or replace function ' || quote_ident(_func_schema) || '.__' || quote_ident(_func_name) || '(_name text) + returns ' || _func_result_type || ' + language plpgsql + AS $function$ + begin + return query execute _query(' || quote_literal(_return_set_value) || '); + end; + $function$;'; + execute _mock_ddl; + _mock_ddl = ' + create or replace function ' || quote_ident(_func_schema) || '.' || quote_ident(_func_name) || _func_args || ' + returns ' || _func_result_type || ' + language ' || _func_language || ' + AS $function$ + select * from ' || quote_ident(_func_schema) || '.__' || quote_ident(_func_name) || + '(' || quote_literal(_return_set_value) || '); + $function$;'; + execute _mock_ddl; + end if; + + if _func_language = 'plpgsql' and _returns_set then + _mock_ddl = ' + create or replace function ' || quote_ident(_func_schema) || '.' || quote_ident(_func_name) || _func_args || ' + returns ' || _func_result_type || ' + language plpgsql + AS $function$ + begin + return query execute _query(' || quote_literal(_return_set_value) || '); + end; + $function$;'; + execute _mock_ddl; + end if; + + if not _returns_set then + _mock_ddl = ' + create or replace function ' || quote_ident(_func_schema) || '.' || quote_ident(_func_name) || _func_args || ' + RETURNS ' || _func_result_type || ' + LANGUAGE ' || _func_language || ' + AS $function$ + select ' || quote_nullable(_return_scalar_value) || '::' || pg_typeof(_return_scalar_value) || '; + $function$;'; + execute _mock_ddl; + end if; +end $procedure$; + + +CREATE OR REPLACE PROCEDURE fake_table( + _table_ident text[], + _make_table_empty boolean default false, + _leave_primary_key boolean default false, + _drop_not_null boolean DEFAULT false, + _drop_collation boolean DEFAULT false +) +--It frees a table from any constraint (we call such a table as a fake) +--faked table is a full copy of _table_name, but has no any constraint +--without foreign and primary things you can do whatever you want in testing context + LANGUAGE plpgsql +AS $procedure$ +declare + _table record; + _fk_table record; + _fake_ddl text; + _not_null_ddl text; +begin + for _table in + select + quote_ident(coalesce((parse_ident(table_ident))[1], '')) table_schema, + quote_ident(coalesce((parse_ident(table_ident))[2], '')) table_name, + coalesce((parse_ident(table_ident))[1], '') table_schema_l, + coalesce((parse_ident(table_ident))[2], '') table_name_l + from + unnest(_table_ident) as t(table_ident) + loop + for _fk_table in + -- collect all table's relations including primary key and unique constraint + select distinct * + from ( + select + fk_schema_name table_schema, fk_table_name table_name + , fk_constraint_name constraint_name, false as is_pk, 1 as ord + from + pg_all_foreign_keys + where + fk_schema_name = _table.table_schema_l and fk_table_name = _table.table_name_l + union all + select + fk_schema_name table_schema, fk_table_name table_name + , fk_constraint_name constraint_name, false as is_pk, 1 as ord + from + pg_all_foreign_keys + where + pk_schema_name = _table.table_schema_l and pk_table_name = _table.table_name_l + union all + select + table_schema, table_name + , constraint_name + , case when constraint_type = 'PRIMARY KEY' then true else false end as is_pk, 2 as ord + from + information_schema.table_constraints + where + table_schema = _table.table_schema_l + and table_name = _table.table_name_l + and constraint_type in ('PRIMARY KEY', 'UNIQUE') + ) as t + order by ord + loop + if not(_leave_primary_key and _fk_table.is_pk) then + _fake_ddl = 'alter table ' || _fk_table.table_schema || '.' || _fk_table.table_name || ' + drop constraint ' || _fk_table.constraint_name || ';'; + execute _fake_ddl; + end if; + end loop; + + if _make_table_empty then + _fake_ddl = 'truncate table ' || _table.table_schema || '.' || _table.table_name || ';'; + execute _fake_ddl; + end if; + + --Free table from not null constraints + _fake_ddl = 'alter table ' || _table.table_schema || '.' || _table.table_name || ' '; + if _drop_not_null then + select + string_agg('alter column ' || t.attname || ' drop not null', ', ') + into + _not_null_ddl + from + pg_catalog.pg_attribute t + where t.attrelid = (_table.table_schema || '.' || _table.table_name)::regclass + and t.attnum > 0 and attnotnull; + + _fake_ddl = _fake_ddl || _not_null_ddl || ';'; + else + _fake_ddl = null; + end if; + + if _fake_ddl is not null then + execute _fake_ddl; + end if; + end loop; +end $procedure$; + +create or replace function call_count( + _call_count int + , _func_schema name + , _func_name name + , _func_args name[]) + RETURNS text + LANGUAGE plpgsql +AS $function$ +declare + _actual_call_count int; + _track_functions_setting text; +begin + select current_setting('track_functions') into _track_functions_setting; + + if _track_functions_setting != 'all' then + return fail('track_functions setting is not set. Must be all'); + end if; + + select calls into _actual_call_count + from pg_stat_xact_user_functions + where funcid = _get_func_oid(_func_schema, _func_name, _func_args); + + return ok( + _actual_call_count = _call_count + , format('routine %I.%I must has been called %L times, actual call count is %L' + , _func_schema, _func_name, _call_count, _actual_call_count) + ); +end $function$; + +create or replace function drop_prepared_statement(_statements text[]) +returns setof bool as $$ +declare + _statement record; +begin + for _statement in select _name from unnest(_statements) as t(_name) loop + if exists(select * from pg_prepared_statements where "name" = _statement._name) then + EXECUTE format('deallocate %I;', _statement._name); + return next true; + else + return next false; + end if; + end loop; +end +$$ +language plpgsql; + + +create or replace procedure print_table_as_json(_table_schema text, _table_name text) + language plpgsql +AS $procedure$ +declare + _ddl text; + _json text; + _columns text; +--returns a query which you can execute and see your table as normal dataset +--note! the returned dataset is limited to 1000 records. that's why you didn't get any jdbc error in dbeaver in case of huge amount of rows +begin + _ddl = ' + select json_agg( + array(select ' || quote_ident(_table_name) || ' from ' || quote_ident(_table_schema) || '.' || quote_ident(_table_name) || ' limit 1000 + )) as j;'; + execute _ddl into _json; + _json = '[' || ltrim(rtrim(_json::text, ']'), '[') || ']'; + + select string_agg(concat(c.column_name, ' ', case when lower(c.data_type) = 'array' then e.data_type || '[]' else c.data_type end), ', ') + into _columns + from information_schema."columns" c + left join information_schema.element_types e + on ((c.table_catalog, c.table_schema, c.table_name, 'TABLE', c.dtd_identifier) + = (e.object_catalog, e.object_schema, e.object_name, e.object_type, e.collection_type_identifier)) + where c.table_schema = _table_schema + and c.table_name = _table_name; + + _json = $$select * from /*$$ || quote_ident(_table_schema) || '.' || quote_ident(_table_name) || $$*/ json_to_recordset('$$ || _json || $$') as t($$ || _columns || $$)$$; + raise notice '%', _json; +end $procedure$; + +CREATE OR REPLACE FUNCTION _get_func_oid(name, name, name[]) + RETURNS oid + LANGUAGE sql +AS $function$ + SELECT oid + FROM tap_funky + WHERE "schema" = $1 + and "name" = $2 + AND args = _funkargs($3) + AND is_visible +$function$ +; + +CREATE OR REPLACE VIEW tap_funky + AS + SELECT + p.oid AS oid, + n.nspname AS schema, + p.proname AS name, + pg_catalog.pg_get_userbyid(p.proowner) AS owner, + proc_name.args AS args, + lower(coalesce( + proc_return."returns", + proc_return.sys_returns)) AS "returns", + p.prolang AS langoid, + p.proisstrict AS is_strict, + _prokind(p.oid) AS kind, + p.prosecdef AS is_definer, + p.proretset AS returns_set, + p.provolatile::char AS volatility, + pg_catalog.pg_function_is_visible(p.oid) AS is_visible, + l.lanname AS langname +FROM pg_catalog.pg_proc p +JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid +LEFT JOIN pg_language l ON l.oid = p.prolang +LEFT JOIN LATERAL ( + SELECT + (n.nspname::text || '.'::text) || p.proname::text AS qualified, + array_to_string(p.proargtypes::regtype[], ',') AS args +) proc_name ON true +LEFT JOIN LATERAL ( + SELECT + CASE + WHEN n.nspname != 'pg_catalog' + THEN pg_get_function_result((concat(proc_name.qualified, '(', proc_name.args, ')')::regprocedure)::oid) + ELSE NULL + END AS "returns", + CASE p.proretset WHEN TRUE THEN 'setof ' ELSE '' END || p.prorettype::regtype AS sys_returns +) AS proc_return ON TRUE; + -- index_is_partial( schema, table, index, description ) CREATE OR REPLACE FUNCTION index_is_partial ( NAME, NAME, NAME, text ) RETURNS TEXT AS $$ @@ -86,4 +402,4 @@ BEGIN 'Index ' || quote_ident($1) || ' should be partial' ); END; -$$ LANGUAGE plpgsql; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/sql/pgtap--unpackaged--0.91.0.sql b/sql/pgtap--unpackaged--0.91.0.sql index e8875c32..9a9bcf57 100644 --- a/sql/pgtap--unpackaged--0.91.0.sql +++ b/sql/pgtap--unpackaged--0.91.0.sql @@ -712,3 +712,10 @@ ALTER EXTENSION pgtap ADD FUNCTION columns_are( NAME, NAME[] ); ALTER EXTENSION pgtap ADD FUNCTION _get_db_owner( NAME ); ALTER EXTENSION pgtap ADD FUNCTION db_owner_is ( NAME, NAME, TEXT ); ALTER EXTENSION pgtap ADD FUNCTION db_owner_is ( NAME, NAME ); + +ALTER EXTENSION pgtap ADD PROCEDURE mock_func( TEXT, TEXT, TEXT, ANYELEMENT ); +ALTER EXTENSION pgtap ADD PROCEDURE fake_table( TEXT[], TEXT[], BOOL, BOOL ); +ALTER EXTENSION pgtap ADD FUNCTION call_count( INT, TEXT, TEXT ); +ALTER EXTENSION pgtap ADD FUNCTION drop_prepared_statement( TEXT ); +ALTER EXTENSION pgtap ADD FUNCTION print_table_as_json( TEXT, TEXT ); +ALTER EXTENSION pgtap ADD FUNCTION _get_func_oid(name, name[]); \ No newline at end of file diff --git a/sql/pgtap.sql.in b/sql/pgtap.sql.in index c1c7ed92..828d0644 100644 --- a/sql/pgtap.sql.in +++ b/sql/pgtap.sql.in @@ -11518,3 +11518,317 @@ RETURNS TEXT AS $$ 'Function ' || quote_ident($1) || '() should not be a procedure' ); $$ LANGUAGE sql; + +--added a column "langname" used in mock_func function +CREATE OR REPLACE VIEW tap_funky + AS SELECT p.oid AS oid, + n.nspname AS schema, + p.proname AS name, + pg_catalog.pg_get_userbyid(p.proowner) AS owner, + array_to_string(p.proargtypes::regtype[], ',') AS args, + CASE p.proretset WHEN TRUE THEN 'setof ' ELSE '' END + || p.prorettype::regtype AS returns, + p.prolang AS langoid, + p.proisstrict AS is_strict, + _prokind(p.oid) AS kind, + p.prosecdef AS is_definer, + p.proretset AS returns_set, + p.provolatile::char AS volatility, + pg_catalog.pg_function_is_visible(p.oid) AS is_visible, + l.lanname AS langname + FROM pg_catalog.pg_proc p + JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid + LEFT JOIN pg_language l ON l.oid = p.prolang +; + +--this procedure creates a mock in place of a real function +create or replace procedure mock_func( + _func_schema text + , _func_name text + , _func_args text + , _return_set_value text default null + , _return_scalar_value anyelement default null::text +) +--creates a mock in place of a real function + LANGUAGE plpgsql +AS $procedure$ +declare + _mock_ddl text; + _func_result_type text; + _func_qualified_name text; + _func_language text; + _returns_set bool; +begin + select "returns", langname, returns_set + into _func_result_type, _func_language, _returns_set + from tap_funky + where "schema" = _func_schema + and "name" = _func_name; + + if _func_language = 'sql' and _returns_set then + _mock_ddl = ' + create or replace function ' || quote_ident(_func_schema) || '.__' || quote_ident(_func_name) || '(_name text) + returns ' || _func_result_type || ' + language plpgsql + AS $function$ + begin + return query execute _query(' || quote_literal(_return_set_value) || '); + end; + $function$;'; + execute _mock_ddl; + _mock_ddl = ' + create or replace function ' || quote_ident(_func_schema) || '.' || quote_ident(_func_name) || _func_args || ' + returns ' || _func_result_type || ' + language ' || _func_language || ' + AS $function$ + select * from ' || quote_ident(_func_schema) || '.__' || quote_ident(_func_name) || + '(' || quote_literal(_return_set_value) || '); + $function$;'; + execute _mock_ddl; + end if; + + if _func_language = 'plpgsql' and _returns_set then + _mock_ddl = ' + create or replace function ' || quote_ident(_func_schema) || '.' || quote_ident(_func_name) || _func_args || ' + returns ' || _func_result_type || ' + language plpgsql + AS $function$ + begin + return query execute _query(' || quote_literal(_return_set_value) || '); + end; + $function$;'; + execute _mock_ddl; + end if; + + if not _returns_set then + _mock_ddl = ' + create or replace function ' || quote_ident(_func_schema) || '.' || quote_ident(_func_name) || _func_args || ' + RETURNS ' || _func_result_type || ' + LANGUAGE ' || _func_language || ' + AS $function$ + select ' || quote_nullable(_return_scalar_value) || '::' || pg_typeof(_return_scalar_value) || '; + $function$;'; + execute _mock_ddl; + end if; +end $procedure$; + +CREATE OR REPLACE PROCEDURE fake_table( + _table_ident text[], + _make_table_empty boolean default false, + _leave_primary_key boolean default false, + _drop_not_null boolean DEFAULT false, + _drop_collation boolean DEFAULT false +) +--It frees a table from any constraint (we call such a table as a fake) +--faked table is a full copy of _table_name, but has no any constraint +--without foreign and primary things you can do whatever you want in testing context + LANGUAGE plpgsql +AS $procedure$ +declare + _table record; + _fk_table record; + _fake_ddl text; + _not_null_ddl text; +begin + for _table in + select + quote_ident(coalesce((parse_ident(table_ident))[1], '')) table_schema, + quote_ident(coalesce((parse_ident(table_ident))[2], '')) table_name, + coalesce((parse_ident(table_ident))[1], '') table_schema_l, + coalesce((parse_ident(table_ident))[2], '') table_name_l + from + unnest(_table_ident) as t(table_ident) + loop + for _fk_table in + -- collect all table's relations including primary key and unique constraint + select distinct * + from ( + select + fk_schema_name table_schema, fk_table_name table_name + , fk_constraint_name constraint_name, false as is_pk, 1 as ord + from + pg_all_foreign_keys + where + fk_schema_name = _table.table_schema_l and fk_table_name = _table.table_name_l + union all + select + fk_schema_name table_schema, fk_table_name table_name + , fk_constraint_name constraint_name, false as is_pk, 1 as ord + from + pg_all_foreign_keys + where + pk_schema_name = _table.table_schema_l and pk_table_name = _table.table_name_l + union all + select + table_schema, table_name + , constraint_name + , case when constraint_type = 'PRIMARY KEY' then true else false end as is_pk, 2 as ord + from + information_schema.table_constraints + where + table_schema = _table.table_schema_l + and table_name = _table.table_name_l + and constraint_type in ('PRIMARY KEY', 'UNIQUE') + ) as t + order by ord + loop + if not(_leave_primary_key and _fk_table.is_pk) then + _fake_ddl = 'alter table ' || _fk_table.table_schema || '.' || _fk_table.table_name || ' + drop constraint ' || _fk_table.constraint_name || ';'; + execute _fake_ddl; + end if; + end loop; + + if _make_table_empty then + _fake_ddl = 'truncate table ' || _table.table_schema || '.' || _table.table_name || ';'; + execute _fake_ddl; + end if; + + --Free table from not null constraints + _fake_ddl = 'alter table ' || _table.table_schema || '.' || _table.table_name || ' '; + if _drop_not_null then + select + string_agg('alter column ' || t.attname || ' drop not null', ', ') + into + _not_null_ddl + from + pg_catalog.pg_attribute t + where t.attrelid = (_table.table_schema || '.' || _table.table_name)::regclass + and t.attnum > 0 and attnotnull; + + _fake_ddl = _fake_ddl || _not_null_ddl || ';'; + else + _fake_ddl = null; + end if; + + if _fake_ddl is not null then + execute _fake_ddl; + end if; + end loop; +end $procedure$; + +create or replace function call_count( + _call_count int + , _func_schema name + , _func_name name + , _func_args name[]) + RETURNS text + LANGUAGE plpgsql +AS $function$ +declare + _actual_call_count int; + _track_functions_setting text; +begin + select current_setting('track_functions') into _track_functions_setting; + + if _track_functions_setting != 'all' then + return fail('track_functions setting is not set. Must be all'); + end if; + + select calls into _actual_call_count + from pg_stat_xact_user_functions + where funcid = _get_func_oid(_func_schema, _func_name, _func_args); + + return ok( + _actual_call_count = _call_count + , format('routine %I.%I must has been called %L times, actual call count is %L' + , _func_schema, _func_name, _call_count, _actual_call_count) + ); +end $function$; + +create or replace function drop_prepared_statement(_statements text[]) +returns setof bool as $$ +declare + _statement record; +begin + for _statement in select _name from unnest(_statements) as t(_name) loop + if exists(select * from pg_prepared_statements where "name" = _statement._name) then + EXECUTE format('deallocate %I;', _statement._name); + return next true; + else + return next false; + end if; + end loop; +end +$$ +language plpgsql; + +create or replace procedure print_table_as_json(in _table_schema text, in _table_name text) + language plpgsql +AS $procedure$ +declare + _ddl text; + _json text; + _columns text; +--returns a query which you can execute and see your table as normal dataset +--note! the returned dataset is limited to 1000 records. that's why you didn't get any jdbc error in dbeaver in case of huge amount of rows +begin + _ddl = ' + select json_agg( + array(select ' || quote_ident(_table_name) || ' from ' || quote_ident(_table_schema) || '.' || quote_ident(_table_name) || ' limit 1000 + )) as j;'; + execute _ddl into _json; + _json = '[' || ltrim(rtrim(_json::text, ']'), '[') || ']'; + + select string_agg(concat(c.column_name, ' ', case when lower(c.data_type) = 'array' then e.data_type || '[]' else c.data_type end), ', ') + into _columns + from information_schema."columns" c + left join information_schema.element_types e + on ((c.table_catalog, c.table_schema, c.table_name, 'TABLE', c.dtd_identifier) + = (e.object_catalog, e.object_schema, e.object_name, e.object_type, e.collection_type_identifier)) + where c.table_schema = _table_schema + and c.table_name = _table_name; + + _json = $$select * from /*$$ || quote_ident(_table_schema) || '.' || quote_ident(_table_name) || $$*/ json_to_recordset('$$ || _json || $$') as t($$ || _columns || $$)$$; + raise notice '%', _json; +end $procedure$; + +CREATE OR REPLACE FUNCTION _get_func_oid(name, name, name[]) + RETURNS oid + LANGUAGE sql +AS $function$ + SELECT oid + FROM tap_funky + WHERE "schema" = $1 + and "name" = $2 + AND args = _funkargs($3) + AND is_visible +$function$ +; + +CREATE OR REPLACE VIEW tap_funky + AS + SELECT + p.oid AS oid, + n.nspname AS schema, + p.proname AS name, + pg_catalog.pg_get_userbyid(p.proowner) AS owner, + proc_name.args AS args, + lower(coalesce( + proc_return."returns", + proc_return.sys_returns)) AS "returns", + p.prolang AS langoid, + p.proisstrict AS is_strict, + _prokind(p.oid) AS kind, + p.prosecdef AS is_definer, + p.proretset AS returns_set, + p.provolatile::char AS volatility, + pg_catalog.pg_function_is_visible(p.oid) AS is_visible, + l.lanname AS langname +FROM pg_catalog.pg_proc p +JOIN pg_catalog.pg_namespace n ON p.pronamespace = n.oid +LEFT JOIN pg_language l ON l.oid = p.prolang +LEFT JOIN LATERAL ( + SELECT + (n.nspname::text || '.'::text) || p.proname::text AS qualified, + array_to_string(p.proargtypes::regtype[], ',') AS args +) proc_name ON true +LEFT JOIN LATERAL ( + SELECT + CASE + WHEN n.nspname != 'pg_catalog' + THEN pg_get_function_result((concat(proc_name.qualified, '(', proc_name.args, ')')::regprocedure)::oid) + ELSE NULL + END AS "returns", + CASE p.proretset WHEN TRUE THEN 'setof ' ELSE '' END || p.prorettype::regtype AS sys_returns +) AS proc_return ON TRUE; \ No newline at end of file diff --git a/test/expected/faketable.out b/test/expected/faketable.out new file mode 100644 index 00000000..7a7da55c --- /dev/null +++ b/test/expected/faketable.out @@ -0,0 +1,16 @@ +\unset ECHO +1..14 +ok 1 - public.parent.id is primary key should pass +ok 2 - public.child.id is not primary key should pass +ok 3 - public.child.parent_id is not foreign key should pass +ok 4 - public.parent.id is not null should pass +ok 5 - public.parent.col is null should pass +ok 6 - public.child.id is null should pass +ok 7 - public.child.parent_id is null should pass +ok 8 - public.child.col is null should pass +ok 9 - table public.parent is empty should pass +ok 10 - table public.child is empty should pass +ok 11 - We can do insert into foreign key column should pass +ok 12 - public.scalar_function called once should pass +ok 13 - public.set_sql_function called twice should pass +ok 14 - public.set_sql_function(text) called once should pass diff --git a/test/expected/funcmock.out b/test/expected/funcmock.out new file mode 100644 index 00000000..2d1ef0f7 --- /dev/null +++ b/test/expected/funcmock.out @@ -0,0 +1,5 @@ +\unset ECHO +1..3 +ok 1 - mock scalar_function should pass +ok 2 - mock sql function returning a set should pass +ok 3 - mock plpgsql function returning a set should pass diff --git a/test/sql/faketable.sql b/test/sql/faketable.sql new file mode 100644 index 00000000..8fbea763 --- /dev/null +++ b/test/sql/faketable.sql @@ -0,0 +1,161 @@ +\unset ECHO +\i test/setup.sql +-- \i sql/pgtap.sql + +SELECT plan(14); +--SELECT * FROM no_plan(); + +-- This will be rolled back. :-) +SET track_functions = 'all'; +SET client_min_messages = warning; + +create or replace function public.scalar_function() +returns time +language plpgsql +as $$ +begin + return now()::time; +end; +$$; + +create or replace function public.set_sql_function() +returns table(id int, f text) +language sql +as $$ + select * from (values(1, 'a'), (2, 'b'), (3, 'c')) as t(id, f); +$$; + +create or replace function public.set_sql_function(_whatever text) +returns table(id int, f text) +language sql +as $$ + select * from (values(1, 'a' || _whatever), (2, 'b' || _whatever)) as t(id, f); +$$; + +CREATE TABLE public.parent( + id int NOT NULL, col text NOT NULL, + CONSTRAINT parent_pk PRIMARY KEY (id) +); + +CREATE TABLE public.child( + id int NOT NULL, + parent_id int NOT NULL, + col text NOT NULL, + CONSTRAINT child_pk PRIMARY KEY (id), + CONSTRAINT child_fk FOREIGN KEY (parent_id) REFERENCES parent(id) +); + +INSERT INTO public.parent(id, col) values(1, 'a'); + +INSERT INTO public.child(id, parent_id, col) values(1, 1, 'b'); + +RESET client_min_messages; + +CREATE FUNCTION test_faking_functionality() RETURNS SETOF TEXT AS $$ +BEGIN + CALL fake_table( + '{public.parent}'::text[], + _make_table_empty => TRUE, + _leave_primary_key => TRUE, + _drop_not_null => FALSE); + + CALL fake_table( + '{public.child}'::text[], + _make_table_empty => TRUE, + _leave_primary_key => FALSE, + _drop_not_null => TRUE); + + RETURN query SELECT * FROM check_test( + col_is_pk('public', 'parent', '{id}'::name[]), + TRUE, + 'public.parent.id is primary key'); + + RETURN query SELECT * FROM check_test( + col_isnt_pk('public', 'child', 'id'), + TRUE, + 'public.child.id is not primary key'); + + RETURN query SELECT * FROM check_test( + col_isnt_fk('public', 'child', 'parent_id'), + TRUE, + 'public.child.parent_id is not foreign key'); + + RETURN query SELECT * FROM check_test( + col_not_null('public', 'parent', 'id', ''), + TRUE, + 'public.parent.id is not null'); + + RETURN query SELECT * FROM check_test( + col_not_null('public', 'parent', 'col', ''), + TRUE, + 'public.parent.col is null'); + + RETURN query SELECT * FROM check_test( + col_is_null('public', 'child', 'id', ''), + TRUE, + 'public.child.id is null'); + + RETURN query SELECT * FROM check_test( + col_is_null('public', 'child', 'parent_id', ''), + TRUE, + 'public.child.parent_id is null'); + + RETURN query SELECT * FROM check_test( + col_is_null('public', 'child', 'col', ''), + TRUE, + 'public.child.col is null'); + + PREPARE parent_all AS SELECT * FROM public.parent; + PREPARE child_all AS SELECT * FROM public.child; + + RETURN query SELECT * FROM check_test( + is_empty('parent_all'), + TRUE, + 'table public.parent is empty'); + + RETURN query SELECT * FROM check_test( + is_empty('child_all'), + TRUE, + 'table public.child is empty'); + + RETURN query SELECT * FROM check_test( + lives_ok('INSERT INTO child(id, parent_id, col) values(1, 108, ''z'')'), + TRUE, + 'We can do insert into foreign key column'); +END; +$$ LANGUAGE plpgsql; + + +SELECT * FROM test_faking_functionality(); + +CREATE FUNCTION test_call_count_functionality() RETURNS SETOF TEXT AS $$ +BEGIN + perform public.scalar_function(); + perform public.set_sql_function(); + perform public.set_sql_function(); + perform public.set_sql_function('whatever'); + + RETURN query SELECT * FROM check_test( + call_count(1, 'public', 'scalar_function', '{}'::name[]), + TRUE, + 'public.scalar_function called once'); + + RETURN query SELECT * FROM check_test( + call_count(2, 'public', 'set_sql_function', '{}'::name[]), + TRUE, + 'public.set_sql_function called twice'); + + RETURN query SELECT * FROM check_test( + call_count(1, 'public', 'set_sql_function', '{text}'::name[]), + TRUE, + 'public.set_sql_function(text) called once'); +END; +$$ LANGUAGE plpgsql; + +SELECT * FROM test_call_count_functionality(); + +RESET track_functions; + +-- Finish the tests and clean up. +SELECT * FROM finish(); +ROLLBACK; diff --git a/test/sql/funcmock.sql b/test/sql/funcmock.sql new file mode 100644 index 00000000..85fde546 --- /dev/null +++ b/test/sql/funcmock.sql @@ -0,0 +1,80 @@ +\unset ECHO +\i test/setup.sql +-- \i sql/pgtap.sql + +SELECT plan(3); +--SELECT * FROM no_plan(); + +-- This will be rolled back. :-) +--SET track_functions = 'all'; + +-- This will be rolled back. :-) +SET client_min_messages = warning; + +create or replace function public.scalar_function() +returns time +language sql +as $$ + select now()::time; +$$; + +create or replace function public.set_sql_function() +returns table(id int, col text) +language sql +as $$ + select * FROM (VALUES(1, 'a'), (2, 'b')) AS t(id, col); +$$; + +create or replace function public.set_plpgsql_function() +returns table(id int, col text) +language plpgsql +as $$ +begin + RETURN query select * FROM (VALUES(1, 'a'), (2, 'b')) AS t(id, col); +END; +$$; + +RESET client_min_messages; + +CREATE FUNCTION test_mocking_functionality() RETURNS SETOF TEXT AS $$ +DECLARE + _hour_before time; + _mock_result time; +BEGIN + _hour_before = now() - INTERVAL '01:00'; + CALL mock_func('public', 'scalar_function', '()' + , _return_scalar_value => _hour_before::time); + _mock_result = scalar_function(); + + RETURN query SELECT * FROM check_test( + is(_mock_result, _hour_before), + TRUE, + 'mock scalar_function'); + + PREPARE mock_set_sql_function AS SELECT * FROM (VALUES(1, 'x'), (2, 'z')) AS t(id, col) ORDER BY id; + CALL mock_func('public', 'set_sql_function', '()' + , _return_set_value => 'mock_set_sql_function'); + PREPARE returned_set_sql_function AS SELECT * FROM set_sql_function() ORDER BY id; + + RETURN query SELECT * FROM check_test( + results_eq('returned_set_sql_function', 'mock_set_sql_function'), + TRUE, + 'mock sql function returning a set'); + + PREPARE mock_set_plpgsql_function AS SELECT * FROM (VALUES(1, 'w'), (2, 'q')) AS t(id, col) ORDER BY id; + CALL mock_func('public', 'set_plpgsql_function', '()' + , _return_set_value => 'mock_set_plpgsql_function'); + PREPARE returned_set_plpgsql_function AS SELECT * FROM set_plpgsql_function() ORDER BY id; + + RETURN query SELECT * FROM check_test( + results_eq('returned_set_plpgsql_function', 'mock_set_plpgsql_function'), + TRUE, + 'mock plpgsql function returning a set'); +END; +$$ LANGUAGE plpgsql; + +SELECT * FROM test_mocking_functionality(); + +-- Finish the tests and clean up. +SELECT * FROM finish(); +ROLLBACK;