Some SQL targeted at PostgreSQL. This was intended as the database backend for user management in an online shop system.
You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 
 

162 lines
5.4 KiB

-- Trigger Funktionen zu Konten --
-- [
create function on_ref_count_null_del_konto()
returns TRIGGER as '
DECLARE
err_msg text;
konto fibu.konto%ROWTYPE;
BEGIN
IF TG_OP <> ''UPDATE'' THEN
err_msg := TG_NAME || '': called for wrong action '' || TG_OP;
RAISE EXCEPTION ''%'', err_msg;
END IF;
IF NEW.used = 0 THEN
select INTO konto * from fibu.konto where kto_nr=NEW.kto_nr;
IF FOUND THEN
delete from fibu.konto where kto_nr=NEW.kto_nr;
END IF;
END IF;
RETURN NEW;
END;
' language 'plpgsql';
create function on_change_kontenplan_check_ranges()
returns TRIGGER as '
DECLARE
kontenplan_row fibu.kontenplan%ROWTYPE;
err_msg text;
BEGIN
IF TG_OP = ''INSERT'' THEN
FOR kontenplan_row IN select * from fibu.kontenplan LOOP
IF (NEW.nr_von >= kontenplan_row.nr_von AND
NEW.nr_von <= kontenplan_row.nr_bis) OR
(NEW.nr_bis >= kontenplan_row.nr_von AND
NEW.nr_bis <= kontenplan_row.nr_bis) OR
(NEW.nr_von < kontenplan_row.nr_von AND
NEW.nr_bis > kontenplan_row.nr_bis) THEN
RAISE EXCEPTION ''range violation'';
END IF;
END LOOP;
RETURN NEW;
END IF;
IF TG_OP = ''UPDATE'' THEN
FOR kontenplan_row IN
select * from fibu.kontenplan where _id_<>NEW._id_
LOOP
IF (NEW.nr_von >= kontenplan_row.nr_von AND
NEW.nr_von <= kontenplan_row.nr_bis) OR
(NEW.nr_bis >= kontenplan_row.nr_von AND
NEW.nr_bis <= kontenplan_row.nr_bis) OR
(NEW.nr_von < kontenplan_row.nr_von AND
NEW.nr_bis > kontenplan_row.nr_bis) THEN
RAISE EXCEPTION ''range violation'';
END IF;
END LOOP;
RETURN NEW;
END IF;
err_msg := TG_NAME || '': called for wrong action '' || TG_OP;
RAISE EXCEPTION ''%'', err_msg;
END;
' language 'plpgsql';
create function on_insert_kontenplan_create_used_konten()
returns TRIGGER as '
DECLARE
err_msg text;
i fibu.kontenplan.nr_von%TYPE;
BEGIN
IF TG_OP <> ''INSERT'' THEN
err_msg := TG_NAME || '': called for wrong action '' || TG_OP;
RAISE EXCEPTION ''%'', err_msg;
END IF;
FOR i IN NEW.nr_von..NEW.nr_bis LOOP
insert into fibu.used_konten (kto_nr, used, konto_typ)
values (i, 0, NEW.konto_typ);
END LOOP;
RETURN NEW;
END;
' language 'plpgsql';
create function on_update_kontenplan_upd_used_konten()
returns TRIGGER as '
DECLARE
err_msg text;
von fibu.kontenplan.nr_von%TYPE;
bis fibu.kontenplan.nr_bis%TYPE;
displacement fibu.kontenplan.nr_von%TYPE;
count fibu.kontenplan.nr_von%TYPE;
i fibu.kontenplan.nr_von%TYPE;
BEGIN
IF TG_OP <> ''UPDATE'' THEN
err_msg := TG_NAME || '': called for wrong action '' || TG_OP;
RAISE EXCEPTION ''%'', err_msg;
END IF;
displacement := NEW.nr_von - OLD.nr_von;
IF (NEW.nr_bis - NEW.nr_von) < (OLD.nr_bis - OLD.nr_von) THEN
count := NEW.nr_bis - NEW.nr_von;
von := OLD.nr_von;
bis := von + count;
FOR i IN von..bis LOOP
update fibu.used_konten set kto_nr=i + displacement,
konto_typ=NEW.konto_typ where kto_nr=i;
END LOOP;
von := bis + 1;
bis := OLD.nr_bis;
FOR i IN von..bis LOOP
delete from fibu.used_konten where kto_nr=i;
END LOOP;
ELSE
von := OLD.nr_von;
bis := OLD.nr_bis;
FOR i IN von..bis LOOP
update fibu.used_konten set kto_nr=i + displacement,
konto_typ=NEW.konto_typ where kto_nr=i;
END LOOP;
von := bis + 1;
bis := NEW.nr_bis;
FOR i IN von..bis LOOP
insert into fibu.used_konten (kto_nr, used, konto_typ)
values (i, 0, NEW.konto_typ);
END LOOP;
END IF;
RETURN NEW;
END;
' language 'plpgsql';
create function on_delete_kontenplan_del_used_konten()
returns TRIGGER as '
DECLARE
err_msg text;
i fibu.kontenplan.nr_von%TYPE;
BEGIN
IF TG_OP <> ''DELETE'' THEN
err_msg := TG_NAME || '': called for wrong action '' || TG_OP;
RAISE EXCEPTION ''%'', err_msg;
END IF;
FOR i IN OLD.nr_von..OLD.nr_bis LOOP
delete from fibu.used_konten where kto_nr=i;
END LOOP;
RETURN OLD;
END;
' language 'plpgsql';
-- ]
-- Ende Trigger --