Merge remote-tracking branch 'origin/master'

This commit is contained in:
Michael Hoennig 2019-04-26 10:26:34 +02:00
commit ef3e8c968b

View File

@ -1,16 +1,16 @@
CREATE FUNCTION historicize() RETURNS trigger CREATE FUNCTION historicize() RETURNS trigger
LANGUAGE plpgsql SECURITY DEFINER
AS $$ AS $$
BEGIN BEGIN
IF (TG_OP = 'INSERT') OR (TG_OP = 'UPDATE') THEN IF (TG_OP = 'INSERT') OR (TG_OP = 'UPDATE') THEN
EXECUTE format('INSERT INTO ' || TG_TABLE_NAME || '_history VALUES (DEFAULT, now(), txid_current(), False, $1.*)') USING NEW; EXECUTE format('INSERT INTO %I_history VALUES (DEFAULT, now(), txid_current(), False, $1.*)', TG_TABLE_NAME) USING NEW;
RETURN NEW; RETURN NEW;
ELSE ELSE
EXECUTE format('INSERT INTO ' || TG_TABLE_NAME || '_history VALUES (DEFAULT, now(), txid_current(), True, $1.*)') USING OLD; EXECUTE format('INSERT INTO %I_history VALUES (DEFAULT, now(), txid_current(), True, $1.*)', TG_TABLE_NAME) USING OLD;
RETURN OLD; RETURN OLD;
END IF; END IF;
END; END;
$$; $$
LANGUAGE plpgsql;
CREATE TABLE person ( CREATE TABLE person (
id serial PRIMARY KEY, id serial PRIMARY KEY,
@ -30,6 +30,38 @@ CREATE TABLE person_history (
CREATE TRIGGER person_historicize AFTER INSERT OR DELETE OR UPDATE ON person FOR EACH ROW EXECUTE PROCEDURE historicize(); CREATE TRIGGER person_historicize AFTER INSERT OR DELETE OR UPDATE ON person FOR EACH ROW EXECUTE PROCEDURE historicize();
CREATE OR REPLACE FUNCTION person_history(transaction bigint, VARIADIC groupby text[]) RETURNS TABLE (
history_id integer,
history_timestamp timestamp,
history_transaction bigint,
history_tombstone boolean,
id integer,
name character varying(50),
email character varying(50)
)
AS $$
BEGIN
RETURN QUERY EXECUTE format('SELECT * FROM person_history WHERE history_id IN (SELECT max(history_id) AS history_id FROM person_history WHERE history_transaction <= $1 GROUP BY %s)', array_to_string(groupby, ', ')) USING transaction;
END;
$$
LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION person_history(VARIADIC groupby text[]) RETURNS TABLE (
history_id integer,
history_timestamp timestamp,
history_transaction bigint,
history_tombstone boolean,
id integer,
name character varying(50),
email character varying(50)
)
AS $$
BEGIN
RETURN QUERY EXECUTE format('SELECT * FROM person_history WHERE history_id IN (SELECT max(history_id) AS history_id FROM person_history GROUP BY %s)', array_to_string(groupby, ', '));
END;
$$
LANGUAGE plpgsql;
INSERT INTO person (name, email) VALUES ('michael', 'michael@hierweck.de'); INSERT INTO person (name, email) VALUES ('michael', 'michael@hierweck.de');
INSERT INTO person (name, email) VALUES ('annika', 'annika@hierweck.de'); INSERT INTO person (name, email) VALUES ('annika', 'annika@hierweck.de');
@ -48,6 +80,3 @@ INSERT INTO person (name, email) VALUES ('ax', 'ax@hierweck.de');
UPDATE person SET email='mxx@hierweck.de' WHERE name='mx'; UPDATE person SET email='mxx@hierweck.de' WHERE name='mx';
UPDATE person SET email='axx@hierweck.de' WHERE name='ax'; UPDATE person SET email='axx@hierweck.de' WHERE name='ax';
COMMIT; COMMIT;
SELECT * FROM person_history WHERE history_id IN (SELECT max(history_id) AS history_id FROM person_history WHERE history_transaction <= 12345 GROUP BY id);
SELECT * FROM person_history WHERE history_id IN (SELECT max(history_id) AS history_id FROM person_history WHERE history_transaction <= 12345 GROUP BY name);