-- allgemeine Funktionen -- -- [ create function start_logging(text, text) returns int4 as ' /* * start_logging(table-name, operation) (INSERT, UPDATE, DELETE) * * Startet das logging zu einer bestimmten table. * * returns: 1 - logging eingeschaltet * 0 - logging war schon eingeschaltet */ DECLARE table_schema text; table_schema_oid int4; trig_name_before text; trig_name_after text; all_actions _text := ''{\"INSERT\", \"UPDATE\", \"DELETE\"}''; actions _text; range int4; query text; BEGIN IF $2 <> ''INSERT'' AND $2 <> ''UPDATE'' AND $2 <> ''DELETE'' AND $2 <> ''CHANGE'' AND $2 <> ''ALL'' THEN RETURN -1; END IF; select into table_schema_oid relnamespace from pg_catalog.pg_class where relname=$1; select into table_schema nspname from pg_catalog.pg_namespace where oid=table_schema_oid; IF $2 = ''ALL'' THEN range := 3; actions := all_actions; ELSE IF $2 = ''CHANGE'' THEN range := 2; actions := ''{''; FOR i IN 1..2 LOOP actions := actions || quote_ident(all_actions[i]); IF i<2 THEN actions := actions || '',''; ELSE actions := actions || ''}''; END IF; END LOOP; ELSE range := 1; actions := ''{'' || quote_ident($2) || ''}''; END IF; END IF; FOR i IN 1..range LOOP trig_name_before := ''log_before_'' || lower(actions[i]) || ''_'' || $1; trig_name_after := ''log_after_'' || lower(actions[i]) || ''_'' || $1; PERFORM * from pg_catalog.pg_trigger where tgname=trig_name_before; IF NOT FOUND THEN query := ''CREATE TRIGGER '' || trig_name_before || '' BEFORE '' || actions[i] || '' ON '' || table_schema || ''.'' || $1 || '' FOR EACH ROW EXECUTE PROCEDURE '' || ''trigger_func.set_history();''; EXECUTE query; query := ''CREATE TRIGGER '' || trig_name_after || '' AFTER '' || actions[i] || '' ON '' || table_schema || ''.'' || $1 || '' FOR EACH ROW EXECUTE PROCEDURE '' || ''trigger_func.set_history();''; EXECUTE query; ELSE RAISE EXCEPTION ''specified trigger not found''; END IF; END LOOP; RETURN 1; END; ' language 'plpgsql'; create function stop_logging(text, text) returns int4 as ' /* * stop_logging(table-name, operation) (INSERT, UPDATE, DELETE) * * Stoppt das logging zu einer bestimmten table. * * returns: 1 - logging eingeschaltet * 0 - logging war schon eingeschaltet */ DECLARE table_schema text; table_schema_oid int4; trig_name_before text; trig_name_after text; all_actions _text := ''{\"INSERT\", \"UPDATE\", \"DELETE\"}''; actions _text; range int4; query text; BEGIN IF $2 <> ''INSERT'' AND $2 <> ''UPDATE'' AND $2 <> ''DELETE'' AND $2 <> ''CHANGE'' AND $2 <> ''ALL'' THEN RETURN -1; END IF; select into table_schema_oid relnamespace from pg_catalog.pg_class where relname=$1; select into table_schema nspname from pg_catalog.pg_namespace where oid=table_schema_oid; IF $2 = ''ALL'' THEN range := 3; actions := all_actions; ELSE IF $2 = ''CHANGE'' THEN range := 2; actions := ''{''; FOR i IN 1..2 LOOP actions := actions || quote_ident(all_actions[i]); IF i<2 THEN actions := actions || '',''; ELSE actions := actions || ''}''; END IF; END LOOP; ELSE range := 1; actions := ''{'' || quote_ident($2) || ''}''; END IF; END IF; FOR i IN 1..range LOOP trig_name_before := ''log_before_'' || lower(actions[i]) || ''_'' || $1; trig_name_after := ''log_after_'' || lower(actions[i]) || ''_'' || $1; PERFORM * from pg_catalog.pg_trigger where tgname=trig_name_before; IF FOUND THEN query := ''DROP TRIGGER '' || trig_name_before || '' ON '' || table_schema || ''.'' || $1 || '';''; EXECUTE query; query := ''DROP TRIGGER '' || trig_name_after || '' ON '' || table_schema || ''.'' || $1 || '';''; EXECUTE query; ELSE RAISE EXCEPTION ''specified trigger not found''; END IF; END LOOP; RETURN 1; END; ' language 'plpgsql'; create function bit2text(bit varying) returns text as ' DECLARE len int4; i int4; conv int4; ret text := ''''; BEGIN len := bit_length($1); FOR i IN 0..len-1 LOOP conv := ($1<>'' || $2-old_len || '' as new_val''; FOR dummy IN EXECUTE sel LOOP END LOOP; ELSE IF old_len > $2 THEN sel := ''select (B'' || quote_literal(bit2text($1)) || ''<<'' || old_len-$2 || '')::BIT('' || $2 || '') as new_val''; FOR dummy IN EXECUTE sel LOOP END LOOP; ELSE RETURN $1; END IF; END IF; RETURN dummy.new_val; END; ' language 'plpgsql'; create function mask_len(text, text, text) returns int4 as ' DECLARE len int4 := 0; result RECORD; query text; i int4 := 0; BEGIN query := ''select bit_length('' || $2 || '') '' || ''as len from '' || $1; FOR result IN EXECUTE query LOOP IF i = 0 THEN len := result.len; i := 1; END IF; IF $3 = ''min'' THEN IF result.len < len THEN len := result.len; END IF; END IF; IF $3 = ''max'' THEN IF result.len > len THEN len := result.len; END IF; END IF; IF $3 IS NULL OR $3 = ''first'' THEN EXIT; END IF; END LOOP; IF NOT FOUND THEN len := 0; END IF; RETURN len; END; ' language 'plpgsql'; create function corrected_mask(text, text, bit varying) returns bit varying as ' DECLARE len int4; new bit varying; BEGIN select INTO len public.mask_len($1, $2, NULL); IF len < bit_length($3) THEN RETURN $3; ELSE RETURN bit_set_len($3, len); END IF; END; ' language 'plpgsql'; create function get_db_comment(text) returns text as ' DECLARE co text; dboid pg_catalog.pg_stat_database.datid%TYPE; BEGIN select into dboid OID from pg_catalog.pg_database where datname=$1; select into co description from pg_catalog.pg_description where objoid=dboid; return co; END; ' language 'plpgsql'; create function get_schema_comment(text) returns text as ' DECLARE co text; schemaoid pg_catalog.pg_class.relnamespace%TYPE; BEGIN select into schemaoid OID from pg_catalog.pg_namespace where nspname=$1; select into co description from pg_catalog.pg_description where objoid=schemaoid; return co; END; ' language 'plpgsql'; create function get_constraint_comment(text) returns text as ' DECLARE co text; conoid pg_catalog.pg_stat_database.datid%TYPE; BEGIN select into conoid OID from pg_catalog.pg_constraint where conname=$1; select into co description from pg_catalog.pg_description where objoid=conoid; return co; END; ' language 'plpgsql'; -- CREATE FUNCTION jdbc_clean(text) RETURNS text AS' -- /* -- * Brauchte ich aufgrund eines Bugs im jdbc Treiber, der LATIN1 nicht -- * korrekt in UNICODE umwandelte. -- * Jetzt ist dies Funktion obsolet. -- * -- */ -- DECLARE -- ret text; -- BEGIN -- SELECT INTO ret replace($1, ''\\\\344'', ''ä''); -- SELECT INTO ret replace(ret, ''\\\\366'', ''ö''); -- SELECT INTO ret replace(ret, ''\\\\374'', ''ü''); -- SELECT INTO ret replace(ret, ''\\\\337'', ''\ß''); -- SELECT INTO ret replace(ret, ''\\\\304'', ''Ä''); -- SELECT INTO ret replace(ret, ''\\\\326'', ''Ö''); -- SELECT INTO ret replace(ret, ''\\\\334'', ''Ü''); -- -- RETURN ret; -- END; --' LANGUAGE 'plpgsql' -- ] -- allgemeine Funktionen --