Skip to content

Commit

Permalink
Merge pull request #61 from QGEP/schema_dispatch_2
Browse files Browse the repository at this point in the history
dispatch tables in different schemas
  • Loading branch information
3nids authored Feb 2, 2018
2 parents 54784cc + 9e9ec4d commit 1e02023
Show file tree
Hide file tree
Showing 92 changed files with 8,884 additions and 8,493 deletions.
4 changes: 3 additions & 1 deletion 00_qgep_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,4 +3,6 @@
------ version 09.08.2014 21:35:25
CREATE EXTENSION IF NOT EXISTS postgis;
CREATE EXTENSION IF NOT EXISTS hstore;
CREATE SCHEMA qgep;
CREATE SCHEMA qgep_sys;
CREATE SCHEMA qgep_vl;
CREATE SCHEMA qgep_od;
84 changes: 42 additions & 42 deletions 01_audit.sql
Original file line number Diff line number Diff line change
Expand Up @@ -26,9 +26,9 @@ BEGIN;
-- by manually executing or uncommenting the following line
-- CREATE EXTENSION hstore;

DROP TABLE IF EXISTS qgep.is_logged_actions;
DROP TABLE IF EXISTS qgep_sys.logged_actions;

CREATE TABLE qgep.is_logged_actions (
CREATE TABLE qgep_sys.logged_actions (
event_id bigserial PRIMARY KEY,
schema_name text NOT NULL,
table_name text NOT NULL,
Expand All @@ -48,46 +48,46 @@ CREATE TABLE qgep.is_logged_actions (
statement_only BOOLEAN NOT NULL
);

REVOKE ALL ON qgep.is_logged_actions FROM public;

COMMENT ON TABLE qgep.is_logged_actions IS 'History of auditable actions on audited tables, from qgep.if_modified_func()';
COMMENT ON COLUMN qgep.is_logged_actions.event_id IS 'Unique identifier for each auditable event';
COMMENT ON COLUMN qgep.is_logged_actions.schema_name IS 'Database schema audited table for this event is in';
COMMENT ON COLUMN qgep.is_logged_actions.table_name IS 'Non-schema-qualified table name of table event occured in';
COMMENT ON COLUMN qgep.is_logged_actions.relid IS 'Table OID. Changes with drop/create. Get with ''tablename''::regclass';
COMMENT ON COLUMN qgep.is_logged_actions.session_user_name IS 'Login / session user whose statement caused the audited event';
COMMENT ON COLUMN qgep.is_logged_actions.action_tstamp_tx IS 'Transaction start timestamp for tx in which audited event occurred';
COMMENT ON COLUMN qgep.is_logged_actions.action_tstamp_stm IS 'Statement start timestamp for tx in which audited event occurred';
COMMENT ON COLUMN qgep.is_logged_actions.action_tstamp_clk IS 'Wall clock time at which audited event''s trigger call occurred';
COMMENT ON COLUMN qgep.is_logged_actions.transaction_id IS 'Identifier of transaction that made the change. May wrap, but unique paired with action_tstamp_tx.';
COMMENT ON COLUMN qgep.is_logged_actions.client_addr IS 'IP address of client that issued query. Null for unix domain socket.';
COMMENT ON COLUMN qgep.is_logged_actions.client_port IS 'Remote peer IP port address of client that issued query. Undefined for unix socket.';
COMMENT ON COLUMN qgep.is_logged_actions.client_query IS 'Top-level query that caused this auditable event. May be more than one statement.';
COMMENT ON COLUMN qgep.is_logged_actions.application_name IS 'Application name set when this audit event occurred. Can be changed in-session by client.';
COMMENT ON COLUMN qgep.is_logged_actions.action IS 'Action type; I = insert, D = delete, U = update, T = truncate';
COMMENT ON COLUMN qgep.is_logged_actions.row_data IS 'Record value. Null for statement-level trigger. For INSERT this is the new tuple. For DELETE and UPDATE it is the old tuple.';
COMMENT ON COLUMN qgep.is_logged_actions.changed_fields IS 'New values of fields changed by UPDATE. Null except for row-level UPDATE events.';
COMMENT ON COLUMN qgep.is_logged_actions.statement_only IS '''t'' if audit event is from an FOR EACH STATEMENT trigger, ''f'' for FOR EACH ROW';

CREATE INDEX logged_actions_relid_idx ON qgep.is_logged_actions(relid);
CREATE INDEX logged_actions_action_tstamp_tx_stm_idx ON qgep.is_logged_actions(action_tstamp_stm);
CREATE INDEX logged_actions_action_idx ON qgep.is_logged_actions(action);

CREATE OR REPLACE FUNCTION qgep.if_modified_func() RETURNS TRIGGER AS $body$
REVOKE ALL ON qgep_sys.logged_actions FROM public;

COMMENT ON TABLE qgep_sys.logged_actions IS 'History of auditable actions on audited tables, from qgep_sys.if_modified_func()';
COMMENT ON COLUMN qgep_sys.logged_actions.event_id IS 'Unique identifier for each auditable event';
COMMENT ON COLUMN qgep_sys.logged_actions.schema_name IS 'Database schema audited table for this event is in';
COMMENT ON COLUMN qgep_sys.logged_actions.table_name IS 'Non-schema-qualified table name of table event occured in';
COMMENT ON COLUMN qgep_sys.logged_actions.relid IS 'Table OID. Changes with drop/create. Get with ''tablename''::regclass';
COMMENT ON COLUMN qgep_sys.logged_actions.session_user_name IS 'Login / session user whose statement caused the audited event';
COMMENT ON COLUMN qgep_sys.logged_actions.action_tstamp_tx IS 'Transaction start timestamp for tx in which audited event occurred';
COMMENT ON COLUMN qgep_sys.logged_actions.action_tstamp_stm IS 'Statement start timestamp for tx in which audited event occurred';
COMMENT ON COLUMN qgep_sys.logged_actions.action_tstamp_clk IS 'Wall clock time at which audited event''s trigger call occurred';
COMMENT ON COLUMN qgep_sys.logged_actions.transaction_id IS 'Identifier of transaction that made the change. May wrap, but unique paired with action_tstamp_tx.';
COMMENT ON COLUMN qgep_sys.logged_actions.client_addr IS 'IP address of client that issued query. Null for unix domain socket.';
COMMENT ON COLUMN qgep_sys.logged_actions.client_port IS 'Remote peer IP port address of client that issued query. Undefined for unix socket.';
COMMENT ON COLUMN qgep_sys.logged_actions.client_query IS 'Top-level query that caused this auditable event. May be more than one statement.';
COMMENT ON COLUMN qgep_sys.logged_actions.application_name IS 'Application name set when this audit event occurred. Can be changed in-session by client.';
COMMENT ON COLUMN qgep_sys.logged_actions.action IS 'Action type; I = insert, D = delete, U = update, T = truncate';
COMMENT ON COLUMN qgep_sys.logged_actions.row_data IS 'Record value. Null for statement-level trigger. For INSERT this is the new tuple. For DELETE and UPDATE it is the old tuple.';
COMMENT ON COLUMN qgep_sys.logged_actions.changed_fields IS 'New values of fields changed by UPDATE. Null except for row-level UPDATE events.';
COMMENT ON COLUMN qgep_sys.logged_actions.statement_only IS '''t'' if audit event is from an FOR EACH STATEMENT trigger, ''f'' for FOR EACH ROW';

CREATE INDEX logged_actions_relid_idx ON qgep_sys.logged_actions(relid);
CREATE INDEX logged_actions_action_tstamp_tx_stm_idx ON qgep_sys.logged_actions(action_tstamp_stm);
CREATE INDEX logged_actions_action_idx ON qgep_sys.logged_actions(action);

CREATE OR REPLACE FUNCTION qgep_sys.if_modified_func() RETURNS TRIGGER AS $body$
DECLARE
audit_row qgep.is_logged_actions;
audit_row qgep_sys.logged_actions;
include_values BOOLEAN;
log_diffs BOOLEAN;
h_old hstore;
h_new hstore;
excluded_cols text[] = ARRAY[]::text[];
BEGIN
IF TG_WHEN <> 'AFTER' THEN
RAISE EXCEPTION 'qgep.if_modified_func() may only run as an AFTER trigger';
RAISE EXCEPTION 'qgep_sys.if_modified_func() may only run as an AFTER trigger';
END IF;

audit_row = ROW(
NEXTVAL('qgep.is_logged_actions_event_id_seq'), -- event_id
NEXTVAL('qgep_sys.logged_actions_event_id_seq'), -- event_id
TG_TABLE_SCHEMA::text, -- schema_name
TG_TABLE_NAME::text, -- table_name
TG_RELID, -- relation OID for much quicker searches
Expand Down Expand Up @@ -127,10 +127,10 @@ BEGIN
ELSIF (TG_LEVEL = 'STATEMENT' AND TG_OP IN ('INSERT','UPDATE','DELETE','TRUNCATE')) THEN
audit_row.statement_only = 't';
ELSE
RAISE EXCEPTION '[qgep.if_modified_func] - Trigger func added as trigger for unhandled case: %, %',TG_OP, TG_LEVEL;
RAISE EXCEPTION '[qgep_sys.if_modified_func] - Trigger func added as trigger for unhandled case: %, %',TG_OP, TG_LEVEL;
RETURN NULL;
END IF;
INSERT INTO qgep.is_logged_actions VALUES (audit_row.*);
INSERT INTO qgep_sys.logged_actions VALUES (audit_row.*);
RETURN NULL;
END;
$body$
Expand All @@ -140,7 +140,7 @@ SET search_path = pg_catalog, public
;


COMMENT ON FUNCTION qgep.if_modified_func() IS $body$
COMMENT ON FUNCTION qgep_sys.if_modified_func() IS $body$
Track changes TO a TABLE at the statement AND/OR row level.

Optional parameters TO TRIGGER IN CREATE TRIGGER call:
Expand Down Expand Up @@ -173,7 +173,7 @@ $body$;



CREATE OR REPLACE FUNCTION qgep.audit_table(target_table regclass, audit_rows BOOLEAN, audit_query_text BOOLEAN, ignored_cols text[]) RETURNS void AS $body$
CREATE OR REPLACE FUNCTION qgep_sys.audit_table(target_table regclass, audit_rows BOOLEAN, audit_query_text BOOLEAN, ignored_cols text[]) RETURNS void AS $body$
DECLARE
stm_targets text = 'INSERT OR UPDATE OR DELETE OR TRUNCATE';
_q_txt text;
Expand All @@ -188,7 +188,7 @@ BEGIN
END IF;
_q_txt = 'CREATE TRIGGER audit_trigger_row AFTER INSERT OR UPDATE OR DELETE ON ' ||
target_table::text ||
' FOR EACH ROW EXECUTE PROCEDURE qgep.if_modified_func(' ||
' FOR EACH ROW EXECUTE PROCEDURE qgep_sys.if_modified_func(' ||
quote_literal(audit_query_text) || _ignored_cols_snip || ');';
RAISE NOTICE '%',_q_txt;
EXECUTE _q_txt;
Expand All @@ -198,7 +198,7 @@ BEGIN

_q_txt = 'CREATE TRIGGER audit_trigger_stm AFTER ' || stm_targets || ' ON ' ||
target_table::text ||
' FOR EACH STATEMENT EXECUTE PROCEDURE qgep.if_modified_func('||
' FOR EACH STATEMENT EXECUTE PROCEDURE qgep_sys.if_modified_func('||
quote_literal(audit_query_text) || ');';
RAISE NOTICE '%',_q_txt;
EXECUTE _q_txt;
Expand All @@ -207,7 +207,7 @@ END;
$body$
LANGUAGE 'plpgsql';

COMMENT ON FUNCTION qgep.audit_table(regclass, BOOLEAN, BOOLEAN, text[]) IS $body$
COMMENT ON FUNCTION qgep_sys.audit_table(regclass, BOOLEAN, BOOLEAN, text[]) IS $body$
ADD auditing support TO a TABLE.

Arguments:
Expand All @@ -218,15 +218,15 @@ Arguments:
$body$;

-- Pg doesn't allow variadic calls with 0 params, so provide a wrapper
CREATE OR REPLACE FUNCTION qgep.audit_table(target_table regclass, audit_rows BOOLEAN, audit_query_text BOOLEAN) RETURNS void AS $body$
SELECT qgep.audit_table($1, $2, $3, ARRAY[]::text[]);
CREATE OR REPLACE FUNCTION qgep_sys.audit_table(target_table regclass, audit_rows BOOLEAN, audit_query_text BOOLEAN) RETURNS void AS $body$
SELECT qgep_sys.audit_table($1, $2, $3, ARRAY[]::text[]);
$body$ LANGUAGE SQL;

-- And provide a convenience call wrapper for the simplest case
-- of row-level logging with no excluded cols and query logging enabled.
--
CREATE OR REPLACE FUNCTION qgep.audit_table(target_table regclass) RETURNS void AS $$
SELECT qgep.audit_table($1, BOOLEAN 't', BOOLEAN 't');
CREATE OR REPLACE FUNCTION qgep_sys.audit_table(target_table regclass) RETURNS void AS $$
SELECT qgep_sys.audit_table($1, BOOLEAN 't', BOOLEAN 't');
$$ LANGUAGE 'sql';

COMMIT;
40 changes: 20 additions & 20 deletions 02_oid_generation.sql
Original file line number Diff line number Diff line change
@@ -1,8 +1,8 @@
-- this file generates a new SQL function to create StandardOIDs for all the qgep.od_* tables.
-- you need to add entries for your organizations into the table qgep.is_oid_prefixes
-- this file generates a new SQL function to create StandardOIDs for all the qgep_od.* tables.
-- you need to add entries for your organizations into the table qgep_sys.oid_prefixes
-- questions regarding this function should be directed to Andreas Neumann, Stadt Uster

CREATE TABLE qgep.is_oid_prefixes
CREATE TABLE qgep_sys.oid_prefixes
(
id serial NOT NULL,
prefix character(8),
Expand All @@ -13,31 +13,31 @@ CREATE TABLE qgep.is_oid_prefixes
WITH (
OIDS=FALSE
);
COMMENT ON TABLE qgep.is_oid_prefixes
COMMENT ON TABLE qgep_sys.oid_prefixes
IS 'This table contains OID prefixes for different communities or organizations. The application or administrator changing this table has to make sure that only one record is set to active.';

-- sample entry for Invalid - you need to adapt this entry later for your own organization
INSERT INTO qgep.is_oid_prefixes (prefix,organization,active) VALUES ('00000000','Invalid',TRUE);
INSERT INTO qgep.is_oid_prefixes (prefix,organization,active) VALUES ('ch11h8mw','Stadt Uster',FALSE);
INSERT INTO qgep.is_oid_prefixes (prefix,organization,active) VALUES ('ch15z36d','SIGE',FALSE);
INSERT INTO qgep.is_oid_prefixes (prefix,organization,active) VALUES ('ch13p7mz','Arbon',FALSE);
INSERT INTO qgep.is_oid_prefixes (prefix,organization,active) VALUES ('ch176dc9','Sigip',FALSE);
INSERT INTO qgep.is_oid_prefixes (prefix,organization,active) VALUES ('ch17f516','Prilly',FALSE);
INSERT INTO qgep.is_oid_prefixes (prefix,organization,active) VALUES ('ch17nq5g','Triform',FALSE);
INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('00000000','Invalid',TRUE);
INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch11h8mw','Stadt Uster',FALSE);
INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch15z36d','SIGE',FALSE);
INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch13p7mz','Arbon',FALSE);
INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch176dc9','Sigip',FALSE);
INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch17f516','Prilly',FALSE);
INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch17nq5g','Triform',FALSE);

CREATE INDEX in_qgep_is_oid_prefixes_active
ON qgep.is_oid_prefixes
ON qgep_sys.oid_prefixes
USING btree
(active );

CREATE UNIQUE INDEX in_qgep_is_oid_prefixes_id
ON qgep.is_oid_prefixes
ON qgep_sys.oid_prefixes
USING btree
(id );

-- function for generating StandardOIDs

CREATE OR REPLACE FUNCTION qgep.generate_oid(table_name text)
CREATE OR REPLACE FUNCTION qgep_sys.generate_oid(schema_name text, table_name text)
RETURNS text AS
$BODY$
DECLARE
Expand All @@ -47,28 +47,28 @@ DECLARE
BEGIN
-- first we have to get the OID prefix
BEGIN
SELECT prefix::text INTO myrec_prefix FROM qgep.is_oid_prefixes WHERE active = TRUE;
SELECT prefix::text INTO myrec_prefix FROM qgep_sys.oid_prefixes WHERE active = TRUE;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE EXCEPTION 'no active record found in table qgep.is_oid_prefixes';
RAISE EXCEPTION 'no active record found in table qgep_sys.oid_prefixes';
WHEN TOO_MANY_ROWS THEN
RAISE EXCEPTION 'more than one active records found in table qgep.is_oid_prefixes';
RAISE EXCEPTION 'more than one active records found in table qgep_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 qgep.is_dictionary_od_table WHERE tablename = table_name;
SELECT shortcut_en INTO STRICT myrec_shortcut FROM qgep_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
SELECT nextval('qgep.seq_' || table_name || '_oid') AS seqval INTO myrec_seq;
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;
Expand Down
Loading

0 comments on commit 1e02023

Please sign in to comment.