CREATE TABLE account_entry_reference_t ( id serial not null primary key, account integer not null references account_t (id), account_entry integer not null references account_entry_t (id) ); CREATE OR REPLACE VIEW joined_account_entry_v AS SELECT ae.id as id, ae.description as description, ae.account as account, ae.created_at as created_at, ae.amount as amount, ae.account_entry_category as account_entry_category, ae.document_no as document_no, ae.fiscal_year as fiscal_year, false as is_reference, 0 as base_account FROM account_entry_t ae UNION SELECT ae.id as id, ae.description as description, aer.account as account, ae.created_at as created_at, ae.amount as amount, ae.account_entry_category as account_entry_category, ae.document_no as document_no, ae.fiscal_year as fiscal_year, true as is_reference, ae.account as base_account FROM account_entry_t ae, account_entry_reference_t aer WHERE ae.id = aer.account_entry; update account_t set description = 'fallback_account' where id = 33; delete from account_t where id = 32; insert into account_t (id, description) values (1000, 'ledger'); update account_entry_t set amount = amount * -1.0 where account=33; update account_entry_t set amount = amount * -1.0 where account in (34,35,36,37); DO $$ DECLARE entry_id integer; BEGIN RAISE NOTICE 'Start migration'; FOR entry_id IN SELECT id FROM account_entry_t WHERE account IN (33,34,35,36,37) LOOP RAISE NOTICE 'About to migrate entry %', entry_id; INSERT INTO account_entry_reference_t (account, account_entry) VALUES (1000, entry_id); END LOOP; END; $$; update account_entry_t set description = 'Miete ' || extract(year from created_at)::text || ' ' || to_char(to_date(extract(month from created_at)::text, 'MM'), 'Month') where account_entry_category = 2 and description = 'Miete'; DO $$ DECLARE entry RECORD; tenant RECORD; BEGIN RAISE NOTICE 'Start migration of tenant accounts'; FOR entry IN SELECT id, description, account FROM account_entry_t WHERE account_entry_category = 2 LOOP RAISE NOTICE 'About to migrate entry %', entry.id; INSERT INTO account_entry_reference_t (account, account_entry) VALUES (1000, entry.id); SELECT * INTO tenant FROM tenant_t WHERE account = entry.account; RAISE NOTICE 'Tenant: % %', tenant.firstname, tenant.lastname; UPDATE account_entry_t SET description = description || ' ' || tenant.firstname || ' ' || tenant.lastname WHERE id = entry.id; END LOOP; END; $$; CREATE OR REPLACE FUNCTION maintain_ledger() RETURNS TRIGGER LANGUAGE plpgsql AS $$ DECLARE tenant RECORD; adjusted_description text; BEGIN IF ((NEW.description = 'Miete') AND (NEW.account_entry_category = 2)) THEN SELECT firstname, lastname INTO tenant FROM tenant_t WHERE account = NEW.account; adjusted_description := 'Miete ' || extract(year from NEW.created_at)::text || ' ' || to_char(to_date(extract(month from NEW.created_at)::text, 'MM'), 'Month') || tenant.firstname || ' ' || tenant.lastname; UPDATE account_entry_t SET description = adjusted_description WHERE id = NEW.id; END IF; INSERT INTO account_entry_reference_t (account, account_entry) VALUES (1000, NEW.id); RETURN NEW; END; $$; CREATE TRIGGER maintain_ledger_trigger AFTER INSERT ON account_entry_t FOR EACH ROW WHEN (NEW.account != 1000 AND NEW.account_entry_category NOT IN (3, 4)) EXECUTE FUNCTION maintain_ledger(); grant select, update on account_entry_reference_t_id_seq to hv2; grant insert on account_entry_reference_t to hv2; grant update on account_entry_t to hv2;