cr_trigger_func_benutzer.sql 7.52 KB
-- Trigger Funktionen zu Kunden --
-- [
create function on_insert_create_konten()
    returns TRIGGER as '
        DECLARE
            err_msg text;
        BEGIN
            IF TG_OP <> ''INSERT'' THEN
                err_msg := TG_NAME || '': called for wrong action '' || TG_OP;
                RAISE EXCEPTION ''%'', err_msg;
            END IF;

            /*
             * Die funktion ins_konto uebernimmt schon alle checks bzgl.
             * Des Nummernbereichs, etc. fuer uns.
             */
            NEW.konto1 := fibu.ins_konto(NEW.konto1, TG_ARGV[0],
                                         fibu.konto_typ(TG_ARGV[0]),
                                         NULL, NULL, NULL);
            IF NEW.konto1 = 0 THEN
                err_msg := TG_NAME || '': cannot create debitor_kto'';
                RAISE EXCEPTION ''%'', err_msg;
            ELSE
                PERFORM fibu.inc_konto_ref_count(NEW.konto1);
            END IF;

            NEW.konto2 := fibu.ins_konto(NEW.konto2, TG_ARGV[1],
                                         fibu.konto_typ(TG_ARGV[1]),
                                         NULL, NULL, NULL);
            IF NEW.konto2 = 0 THEN
                err_msg := TG_NAME || '': cannot create kreditor_kto'';
                RAISE EXCEPTION ''%'', err_msg;
            ELSE
                PERFORM fibu.inc_konto_ref_count(NEW.konto2);
            END IF;

            RETURN NEW;
        END;
    ' LANGUAGE 'plpgsql';

create function on_update_update_konten()
    returns TRIGGER as '
        DECLARE
            err_msg text;
            range fibu.kontenplan%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.konto1 <> OLD.konto1 THEN
                NEW.konto1 := fibu.ins_konto(NEW.konto1,TG_ARGV[0],
                                             fibu.konto_typ(TG_ARGV[0]),
                                             NULL, NULL, NULL);

                IF NEW.konto1 = 0 THEN
                    err_msg := TG_NAME || '': cannot create debitor_kto'';
                    RAISE EXCEPTION ''%'', err_msg;
                ELSE
                    PERFORM fibu.inc_konto_ref_count(NEW.konto1);
                    PERFORM fibu.dec_konto_ref_count(OLD.konto1);
                END IF;
            END IF;

            IF NEW.konto2 <> OLD.konto2 THEN
                NEW.konto2 := fibu.ins_konto(NEW.konto2,TG_ARGV[1],
                                             fibu.konto_typ(TG_ARGV[1]),
                                             NULL, NULL, NULL);

                IF NEW.konto2 = 0 THEN
                    err_msg := TG_NAME || '': cannot create kreditor_kto'';
                    RAISE EXCEPTION ''%'', err_msg;
                ELSE
                    PERFORM fibu.inc_konto_ref_count(NEW.konto2);
                    PERFORM fibu.dec_konto_ref_count(OLD.konto2);
                END IF;
            END IF;

            RETURN NEW;
        END;
    ' LANGUAGE 'plpgsql';

create function on_delete_dec_konto_ref_count()
    returns TRIGGER as '
        BEGIN
            PERFORM fibu.dec_konto_ref_count(OLD.konto1);
            PERFORM fibu.dec_konto_ref_count(OLD.konto2);

            RETURN OLD;
        END;
    ' language 'plpgsql';

CREATE FUNCTION on_change_one_null()
    RETURNS TRIGGER AS '
        DECLARE
            err_msg text;
        BEGIN
            IF TG_OP = ''INSERT'' THEN
                IF (NEW.id_person IS NULL AND NEW.id_firma IS NULL) OR
                   (NEW.id_person IS NOT NULL AND NEW.id_firma IS NOT NULL) THEN
                    err_msg := TG_NAME || '': both or none are NULL'';
                    RAISE EXCEPTION ''%'', err_msg;
                ELSE
                    RETURN NEW;
                END IF;
            END IF;

            /*
             * Bei einem update gibt es mehrere Moeglichkeiten:
             * 1. weder id_person noch id_firma werden veraendert:
             *    Dann passiert in dieser Funktion gar nichts.
             * 2. entweder id_person oder id_firma wird veraendert:
             *    - id_person oder id_firma werden gesetzt und das
             *      jeweils andere Feld wird auf NULL gesetzt.
             *    - sind nach dem update beide NULL wird das update nicht
             *      ausgefueht und eine Fehlermeldung ausgegeben.
             * 3. beide werden verandert:
             *    - wird fuer beide Felder ein neuer Wert angegeben, so
             *      geht diese Funktion davon aus das das bisher NULL
             *      enthaltende Feld gesetzt werden soll (diese Situation
             *      sollte allerdings moeglichst immer vom Frontend abgefangen
             *      werden, ein Kunde kann nur entweder eine Person oder eine
             *      Firma sein, nicht beides.
             */
            IF TG_OP = ''UPDATE'' THEN
                IF OLD.id_person IS NOT NULL AND 
                   NEW.id_firma IS NOT NULL THEN
                    NEW.id_person := NULL;
                END IF;
                IF OLD.id_firma IS NOT NULL AND 
                   NEW.id_person IS NOT NULL THEN
                    NEW.id_firma := NULL;
                END IF;

                IF NEW.id_person IS NULL AND NEW.id_FIRMA IS NULL THEN
                    RAISE EXCEPTION ''change_kunde_trigger: both are NULL'';
                END IF;

                RETURN NEW;
            END IF;

            err_msg := TG_NAME || '': called for wrong action '' || TG_OP;
            RAISE EXCEPTION ''%'', err_msg;
        END;
    ' LANGUAGE 'plpgsql';

CREATE FUNCTION on_change_one_null2()
    RETURNS TRIGGER AS '
        DECLARE
            err_msg text;
        BEGIN
            IF TG_OP = ''INSERT'' THEN
                IF (NEW.id_person IS NULL AND 
                    NEW.id_firma IS NULL AND
                    NEW.id_benutzer IS NULL) OR
                   (NEW.id_person IS NOT NULL AND 
                    NEW.id_benutzer IS NOT NULL) OR
                   (NEW.id_firma IS NOT NULL AND
                    NEW.id_benutzer IS NOT NULL) OR
                   (NEW.id_firma IS NOT NULL AND
                    NEW.id_person IS NOT NULL) THEN
                    err_msg := TG_NAME || '': all or none are NULL'';
                    RAISE EXCEPTION ''%'', err_msg;
                ELSE
                    RETURN NEW;
                END IF;
            END IF;

            IF TG_OP = ''UPDATE'' THEN
                IF OLD.id_person IS NOT NULL AND 
                   (NEW.id_firma IS NOT NULL OR
                    NEW.id_benutzer IS NOT NULL) THEN
                    NEW.id_person := NULL;
                END IF;
                IF OLD.id_firma IS NOT NULL AND 
                   (NEW.id_person IS NOT NULL OR
                    NEW id_benutzer IS NOT NULL) THEN
                    NEW.id_firma := NULL;
                END IF;
                IF OLD.id_benutzer IS NOT NULL AND 
                   (NEW.id_person IS NOT NULL OR
                    NEW.id_firma IS NOT NULL) THEN
                    NEW.id_benutzer := NULL;
                END IF;

                IF NEW.id_person IS NULL AND 
                   NEW.id_firma IS NULL AND
                   NEW.id_benutzer IS NULL THEN
                    RAISE EXCEPTION ''change_kunde_trigger: all are NULL'';
                END IF;

                RETURN NEW;
            END IF;

            err_msg := TG_NAME || '': called for wrong action '' || TG_OP;
            RAISE EXCEPTION ''%'', err_msg;
        END;
    ' LANGUAGE 'plpgsql';
-- ]
-- Ende Triggerfunktionen zu Kunden --