Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

harmonize trigger enabling/disabling #381

Merged
merged 69 commits into from
Sep 4, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
69 commits
Select commit Hold shift + click to select a range
811a6f6
add function to enable/disable last_modification_triggers
cymed Aug 15, 2024
45a78a9
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Aug 15, 2024
3694166
remove one "END IF";
cymed Aug 15, 2024
8daa554
call on Interlis import
cymed Aug 16, 2024
a1e4213
pass action name as string
cymed Aug 16, 2024
4968a51
typo fix
cymed Aug 16, 2024
00636e0
alter logger string
cymed Aug 19, 2024
15ecb27
harmonize symbology triggers too
cymed Aug 27, 2024
b6d94ba
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Aug 27, 2024
526f98d
fix plugin side
cymed Aug 27, 2024
0f6f1fe
use LIKE pattern to pass CI
cymed Aug 27, 2024
a81f0bb
add docs
cymed Aug 27, 2024
e856cb4
Revert "add docs"
cymed Aug 27, 2024
548267e
Merge branch 'teksi:main' into last-modification-switch
cymed Aug 27, 2024
8646767
re-update docs
cymed Aug 27, 2024
75bc153
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Aug 27, 2024
d554573
Update datamodel/changelogs/0001/02_sys.sql
cymed Aug 30, 2024
0c02cf2
Update datamodel/changelogs/0001/02_sys.sql
cymed Aug 30, 2024
a02c998
Update docs/en/user-guide/How-To/index.rst
cymed Aug 30, 2024
7874cb1
syntax fix
cymed Aug 30, 2024
d082ef2
moving functions from sys to app
cymed Aug 30, 2024
8299f6e
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Aug 30, 2024
97792b3
move last_modified and oid default
cymed Sep 2, 2024
b1a67e7
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 2, 2024
be04ba3
syntax error
cymed Sep 2, 2024
50c0536
fix indent
cymed Sep 2, 2024
97b7b08
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 2, 2024
007fbaf
remove last_modified from kek
cymed Sep 2, 2024
2b3c4ba
remove from control cable
cymed Sep 2, 2024
b52ed4d
remove aquifier trigger
cymed Sep 2, 2024
5938054
move oid function
cymed Sep 2, 2024
67b336e
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 2, 2024
72ff392
remove defaults from changelogs
cymed Sep 2, 2024
7006597
Update 03_tww_db_dss.sql
cymed Sep 2, 2024
e8afe31
alter in databaseutils
cymed Sep 2, 2024
89feae1
Update 03_tww_control_cable_db_sia405.sql
cymed Sep 2, 2024
f8339e3
remove defaults
cymed Sep 2, 2024
0e1cc28
batch rename tww_sys.generate_oid to tww_app.generate_oid
cymed Sep 2, 2024
f361bca
typeError
cymed Sep 2, 2024
20eed6b
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 2, 2024
e324e6e
Update set_defaults_and_triggers.py
cymed Sep 2, 2024
4e8d27a
Update set_defaults_and_triggers.py
cymed Sep 2, 2024
4f4be2d
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 2, 2024
58b66ff
Update set_defaults_and_triggers.py
cymed Sep 2, 2024
c164b22
Update set_defaults_and_triggers.py
cymed Sep 2, 2024
a12adb2
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 2, 2024
2aec7b6
Update set_defaults_and_triggers.py
cymed Sep 2, 2024
79279eb
load triggers before pirogue view creation
cymed Sep 2, 2024
22f4f88
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 2, 2024
2368999
fix last modification
cymed Sep 3, 2024
399901e
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 3, 2024
4a22040
set default values via triggers
cymed Sep 3, 2024
81e618e
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 3, 2024
37767e9
add language
cymed Sep 3, 2024
2add0c4
Update organisation_functions.sql
cymed Sep 3, 2024
4921711
add unset triggers
cymed Sep 3, 2024
cb83fcc
[pre-commit.ci] auto fixes from pre-commit.com hooks
pre-commit-ci[bot] Sep 3, 2024
0db35e0
Update plugin/teksi_wastewater/interlis/interlis_importer_exporter.py
cymed Sep 3, 2024
5218422
modification_functions.sql
cymed Sep 3, 2024
1ac8d1e
move functions to folder
cymed Sep 3, 2024
67f475d
move back symbology function for patching merge conflict
cymed Sep 3, 2024
867483e
and back into folder again
cymed Sep 3, 2024
4ea83ab
update symbology_functions from main
cymed Sep 3, 2024
f7cbb04
Revert "update symbology_functions from main"
cymed Sep 3, 2024
b7cc0e7
Revert "and back into folder again"
cymed Sep 3, 2024
fd44d7c
Merge branch 'teksi:main' into last-modification-switch
cymed Sep 3, 2024
2e645e9
move again
cymed Sep 3, 2024
3d11b38
mor erach direction change
cymed Sep 3, 2024
a63d0da
Fix check_oid_prefix()
ponceta Sep 3, 2024
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
18 changes: 13 additions & 5 deletions datamodel/app/create_app.py
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,7 @@
import psycopg2 as psycopg

from pirogue import MultipleInheritance, SimpleJoins, SingleInheritance
from triggers.set_defaults_and_triggers import set_defaults_and_triggers
from view.vw_tww_additional_ws import vw_tww_additional_ws
from view.vw_tww_reach import vw_tww_reach
from view.vw_tww_wastewater_structure import vw_tww_wastewater_structure
Expand Down Expand Up @@ -61,11 +62,13 @@ def create_app(

run_sql("CREATE SCHEMA tww_app;", pg_service)

run_sql_file("symbology_functions.sql", pg_service)
run_sql_file("reach_direction_change.sql", pg_service, variables)
run_sql_file("14_geometry_functions.sql", pg_service, variables)
run_sql_file("update_catchment_area_totals.sql", pg_service, variables)
run_sql_file("organisation_functions.sql", pg_service, variables)
run_sql_file("functions/oid_functions.sql", pg_service, variables)
run_sql_file("functions/modification_functions.sql", pg_service)
run_sql_file("functions/symbology_functions.sql", pg_service)
run_sql_file("functions/reach_direction_change.sql", pg_service, variables)
run_sql_file("functions/14_geometry_functions.sql", pg_service, variables)
run_sql_file("functions/update_catchment_area_totals.sql", pg_service, variables)
run_sql_file("functions/organisation_functions.sql", pg_service, variables)

# open YAML files
if tww_reach_extra:
Expand Down Expand Up @@ -110,6 +113,9 @@ def create_app(
"reservoir": "connection_object",
"individual_surface": "connection_object",
"fountain": "connection_object",
# surface_runoff_parameters
"param_ca_general": "surface_runoff_parameters",
"param_ca_mouse1": "surface_runoff_parameters",
# overflow
"leapingweir": "overflow",
"prank_weir": "overflow",
Expand All @@ -123,6 +129,8 @@ def create_app(
"drainage_system": "zone",
}

set_defaults_and_triggers(pg_service, SingleInheritances)

for key in SingleInheritances:
SingleInheritance(
"tww_od." + SingleInheritances[key],
Expand Down
72 changes: 72 additions & 0 deletions datamodel/app/functions/modification_functions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,72 @@
------ LAST MODIFIED -----
CREATE FUNCTION tww_app.modification_last_modified() RETURNS trigger AS $$
BEGIN
NEW.last_modification := TIMEOFDAY();

RETURN NEW;
END;
$$ LANGUAGE PLPGSQL;

CREATE FUNCTION tww_app.modification_last_modified_parent() RETURNS trigger AS $$
DECLARE
table_name TEXT;
BEGIN
table_name = TG_ARGV[0];

EXECUTE '
UPDATE ' || table_name || '
SET last_modification = TIMEOFDAY()::timestamp
WHERE obj_id = ''' || NEW.obj_id || '''
';
RETURN NEW;
END;
$$ LANGUAGE PLPGSQL;

CREATE OR REPLACE FUNCTION tww_app.alter_modification_triggers(action_name text) RETURNS VOID AS
$DO$
DECLARE
schdf text;
tbldf text;
trig text;
BEGIN
IF NOT (action_name ILIKE ANY(ARRAY['ENABLE','DISABLE'])) THEN
RAISE NOTICE '% not a valid input',action_name;
RETURN;
ELSE
FOR schdf,tbldf, trig IN
SELECT
c.relnamespace ::regnamespace::text,
c.relname,
t.tgname
FROM pg_trigger t
INNER JOIN pg_class c on t.tgrelid=c.oid
INNER JOIN pg_proc p on t.tgfoid=p.oid
WHERE p.proname LIKE 'modification_%'
AND p.pronamespace::regnamespace::text = 'tww_app'
LOOP
EXECUTE FORMAT('ALTER TABLE %I.%I %s TRIGGER %I',schdf,tbldf,upper(action_name),trig);
END LOOP;

RETURN;
END IF;
END;
$DO$
LANGUAGE plpgsql SECURITY DEFINER;

CREATE OR REPLACE FUNCTION tww_app.check_modification_enabled() RETURNS BOOL AS
$DO$
DECLARE _disabled_count numeric;
BEGIN
SELECT count(*) into _disabled_count
FROM pg_trigger t
INNER JOIN pg_class c on t.tgrelid=c.oid
INNER JOIN pg_proc p on t.tgfoid=p.oid
WHERE
p.proname LIKE 'modification_%'
AND p.pronamespace::regnamespace::text = 'tww_app'

AND t.tgenabled = 'D';
RETURN _disabled_count=0;
END;
$DO$
LANGUAGE plpgsql SECURITY DEFINER;
42 changes: 42 additions & 0 deletions datamodel/app/functions/oid_functions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
-- function for generating StandardOIDs

CREATE OR REPLACE FUNCTION tww_app.generate_oid(schema_name text, table_name text)
RETURNS text AS
$BODY$
DECLARE
myrec_prefix record;
myrec_shortcut record;
myrec_seq record;
BEGIN
-- first we have to get the OID prefix
BEGIN
SELECT prefix::text INTO myrec_prefix FROM tww_sys.oid_prefixes WHERE active = TRUE;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE EXCEPTION 'no active record found in table tww_sys.oid_prefixes';
WHEN TOO_MANY_ROWS THEN
RAISE EXCEPTION 'more than one active records found in table tww_sys.oid_prefixes';
END;
-- test if prefix is of correct length
IF char_length(myrec_prefix.prefix) != 8 THEN
RAISE EXCEPTION 'character length of prefix must be 8';
END IF;
--get table 2char shortcut
BEGIN
SELECT shortcut_en INTO STRICT myrec_shortcut FROM tww_sys.dictionary_od_table WHERE tablename = table_name;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE EXCEPTION 'dictionary entry for table % not found', table_name;
WHEN TOO_MANY_ROWS THEN
RAISE EXCEPTION 'dictonary entry for table % not unique', table_name;
END;
--get sequence for table
EXECUTE format('SELECT nextval(''%1$I.seq_%2$I_oid'') AS seqval', schema_name, table_name) INTO myrec_seq;
IF NOT FOUND THEN
RAISE EXCEPTION 'sequence for table % not found', table_name;
END IF;
RETURN myrec_prefix.prefix || myrec_shortcut.shortcut_en || to_char(myrec_seq.seqval,'FM000000');
END;
$BODY$
LANGUAGE plpgsql STABLE
COST 100;
138 changes: 138 additions & 0 deletions datamodel/app/functions/organisation_functions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,138 @@
CREATE OR REPLACE FUNCTION tww_app.set_organisations_active(_undo_existing boolean default false)
RETURNS void AS
$BODY$
DECLARE
schm text;
tbl text;
col text;
BEGIN
IF _undo_existing THEN
UPDATE tww_od.organisation
SET tww_active=FALSE;
ELSE NULL;
END IF;
FOR schm,tbl,col IN
SELECT tc.table_schema,
tc.table_name,
kcu.column_name
FROM (SELECT constraint_name FROM information_schema.constraint_column_usage
WHERE table_schema='tww_od'
AND table_name='organisation'
AND column_name='obj_id'
AND constraint_name NOT LIKE'pkey%')ccu
INNER JOIN information_schema.key_column_usage AS kcu
ON ccu.constraint_name = kcu.constraint_name
INNER JOIN information_schema.table_constraints AS tc
ON tc.constraint_name = kcu.constraint_name
LOOP
EXECUTE format($$ UPDATE tww_od.organisation
SET tww_active=TRUE
WHERE obj_id IN (SELECT DISTINCT %I FROM %I.%I)$$, col,schm,tbl);
END LOOP;
END;
$BODY$
LANGUAGE plpgsql VOLATILE;

-- function for retrieving default obj_id
CREATE OR REPLACE FUNCTION tww_app.get_default_values(field_name text)
RETURNS varchar(16) AS
$BODY$
DECLARE
myrec record;
BEGIN
BEGIN
SELECT value_obj_id::varchar(16) INTO myrec FROM tww_od.default_values WHERE fieldname = field_name;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE WARNING 'Field name % not found in table tww_od.default_values. Returning NULL',field_name;
RETURN NULL;
END;
RETURN myrec.value_obj_id;
END;
$BODY$
LANGUAGE plpgsql STABLE SECURITY DEFINER
COST 100;

-- Set defaults on all fk_provider,fk_dataowner,fk_owner
CREATE OR REPLACE FUNCTION tww_app.ft_set_default_values()
RETURNS TRIGGER AS
$BODY$
DECLARE
sch text;
tbl text;
col text;
ttp text;
BEGIN
FOR sch,tbl,col,ttp IN
SELECT
t.table_schema,
c.table_name,
c.column_name,
CASE WHEN t.table_type = 'BASE TABLE' then 'TABLE' ELSE t.table_type END

FROM information_schema.columns c
LEFT JOIN information_schema.tables t
ON c.table_name = t.table_name
and c.table_schema = t.table_schema
WHERE c.column_name = NEW.fieldname
and ((c.table_schema ='tww_od'
and t.table_type = 'BASE TABLE')
OR (c.table_schema ='tww_app'
and t.table_type = 'VIEW'))
LOOP
EXECUTE format($$ ALTER %4$s %1$I.%2$I ALTER COLUMN %3$I SET DEFAULT tww_app.get_default_values('%2$s') $$, sch,tbl,col,ttp);
END LOOP;
RETURN NEW;
END;
$BODY$
LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION tww_app.ft_unset_default_values()
RETURNS TRIGGER AS
$BODY$
DECLARE
sch text;
tbl text;
col text;
ttp text;
BEGIN
FOR sch,tbl,col,ttp IN
SELECT
t.table_schema,
c.table_name,
c.column_name,
CASE WHEN t.table_type = 'BASE TABLE' then 'TABLE' ELSE t.table_type END

FROM information_schema.columns c
LEFT JOIN information_schema.tables t
ON c.table_name = t.table_name
and c.table_schema = t.table_schema
WHERE c.column_name = OLD.fieldname
and ((c.table_schema ='tww_od'
and t.table_type = 'BASE TABLE')
OR (c.table_schema ='tww_app'
and t.table_type = 'VIEW'))
LOOP
EXECUTE format($$ ALTER %4$s %1$I.%2$I ALTER COLUMN %3$I DROP DEFAULT $$, sch,tbl,col,ttp);
END LOOP;
RETURN NULL;
END;
$BODY$
LANGUAGE plpgsql;


DROP TRIGGER IF EXISTS set_default_values ON tww_od.default_values;

CREATE TRIGGER set_default_values
BEFORE INSERT OR UPDATE
ON tww_od.default_values
FOR EACH ROW
EXECUTE PROCEDURE tww_app.ft_set_default_values();

DROP TRIGGER IF EXISTS unset_default_values ON tww_od.default_values;

CREATE TRIGGER unset_default_values
BEFORE DELETE
ON tww_od.default_values
FOR EACH ROW
EXECUTE PROCEDURE tww_app.ft_unset_default_values();
Loading