70 lines
2.1 KiB
PL/PgSQL
70 lines
2.1 KiB
PL/PgSQL
-- Créer le schéma audit
|
||
|
||
CREATE SCHEMA IF NOT EXISTS audit;
|
||
|
||
-- 1️⃣ Créer la table d’audit
|
||
CREATE TABLE audit.personne_audit_log (
|
||
audit_id SERIAL PRIMARY KEY,
|
||
personne_id BIGINT,
|
||
action VARCHAR(10),
|
||
changed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||
old_data JSONB,
|
||
new_data JSONB
|
||
);
|
||
|
||
-- 2️⃣ Créer la fonction d’audit
|
||
CREATE OR REPLACE FUNCTION audit.audit_personne_changes()
|
||
RETURNS TRIGGER AS $$
|
||
BEGIN
|
||
IF (TG_OP = 'UPDATE') THEN
|
||
INSERT INTO audit.personne_audit_log (personne_id, action, old_data, new_data)
|
||
VALUES (
|
||
OLD.id,
|
||
TG_OP,
|
||
to_jsonb(OLD),
|
||
to_jsonb(NEW)
|
||
);
|
||
RETURN NEW;
|
||
ELSIF (TG_OP = 'INSERT') THEN
|
||
INSERT INTO audit.personne_audit_log (personne_id, action, new_data)
|
||
VALUES (
|
||
NEW.id,
|
||
TG_OP,
|
||
to_jsonb(NEW)
|
||
);
|
||
RETURN NEW;
|
||
ELSIF (TG_OP = 'DELETE') THEN
|
||
INSERT INTO audit.personne_audit_log (personne_id, action, old_data)
|
||
VALUES (
|
||
OLD.id,
|
||
TG_OP,
|
||
to_jsonb(OLD)
|
||
);
|
||
RETURN OLD;
|
||
END IF;
|
||
END;
|
||
$$ LANGUAGE plpgsql;
|
||
|
||
-- 3️⃣ Créer le trigger
|
||
CREATE TRIGGER trigger_audit_personne
|
||
AFTER INSERT OR UPDATE OR DELETE ON personne
|
||
FOR EACH ROW
|
||
EXECUTE FUNCTION audit.audit_personne_changes();
|
||
|
||
|
||
|
||
GRANT USAGE ON SCHEMA audit TO infocad_user;
|
||
GRANT INSERT, SELECT ON audit.personne_audit_log TO infocad_user;
|
||
|
||
SELECT
|
||
personne_id,
|
||
action,
|
||
changed_at,
|
||
old_data->>'prenom_ou_raison_sociale' AS prenom_before,
|
||
new_data->>'prenom_ou_raison_sociale' AS prenom_after,
|
||
old_data->>'updated_by' AS updated_by_before,
|
||
new_data->>'updated_by' AS updated_by_after
|
||
FROM audit.personne_audit_log
|
||
WHERE personne_id = 10
|
||
ORDER BY changed_at DESC;
|