Implment sql audit log

This commit is contained in:
2024-10-31 00:14:46 +01:00
parent 50ca3bc2bc
commit 4317f237b5

View File

@@ -1,7 +1,4 @@
create table guild (
id integer primary key,
name blob
);
create table guild (id integer primary key, name blob);
create unique index idx_guild_name on guild(name);
create table player (
@@ -23,4 +20,202 @@ create table note (
content blob,
timestamp string,
player integer references player(id)
);
);
create table audit_log (
id integer primary key,
table_name text not null,
row_id integer not null,
action text not null,
changes text,
timestamp text default current_timestamp
);
create trigger guild_insert_audit
after
insert on guild begin
insert into audit_log (table_name, row_id, action, changes)
values (
'guild',
new.id,
'INSERT',
json_object('name', new.name)
);
end;
create trigger guild_update_audit
after
update on guild begin
insert into audit_log (table_name, row_id, action, changes)
values (
'guild',
new.id,
'UPDATE',
json_object('old_name', old.name, 'new_name', new.name)
);
end;
create trigger guild_delete_audit
after delete on guild begin
insert into audit_log (table_name, row_id, action, changes)
values (
'guild',
old.id,
'DELETE',
json_object('name', old.name)
);
end;
create trigger player_insert_audit
after
insert on player begin
insert into audit_log (table_name, row_id, action, changes)
values (
'player',
new.id,
'INSERT',
json_object('name', new.name, 'guild', new.guild)
);
end;
create trigger player_update_audit
after
update on player begin
insert into audit_log (table_name, row_id, action, changes)
values (
'player',
new.id,
'UPDATE',
json_object(
'old_name',
old.name,
'new_name',
new.name,
'old_guild',
old.guild,
'new_guild',
new.guild
)
);
end;
create trigger player_delete_audit
after delete on player begin
insert into audit_log (table_name, row_id, action, changes)
values (
'player',
old.id,
'DELETE',
json_object('name', old.name, 'guild', old.guild)
);
end;
create trigger association_insert_audit
after
insert on association begin
insert into audit_log (table_name, row_id, action, changes)
values (
'association',
new.id,
'INSERT',
json_object('lhs', new.lhs, 'rhs', new.rhs, 'note', new.note)
);
end;
create trigger association_update_audit
after
update on association begin
insert into audit_log (table_name, row_id, action, changes)
values (
'association',
new.id,
'UPDATE',
json_object(
'old_lhs',
old.lhs,
'new_lhs',
new.lhs,
'old_rhs',
old.rhs,
'new_rhs',
new.rhs,
'old_note',
old.note,
'new_note',
new.note
)
);
end;
create trigger association_delete_audit
after delete on association begin
insert into audit_log (table_name, row_id, action, changes)
values (
'association',
old.id,
'DELETE',
json_object('lhs', old.lhs, 'rhs', old.rhs, 'note', old.note)
);
end;
create trigger note_insert_audit
after
insert on note begin
insert into audit_log (table_name, row_id, action, changes)
values (
'note',
new.id,
'INSERT',
json_object(
'content',
new.content,
'timestamp',
new.timestamp,
'player',
new.player
)
);
end;
create trigger note_update_audit
after
update on note begin
insert into audit_log (table_name, row_id, action, changes)
values (
'note',
new.id,
'UPDATE',
json_object(
'old_content',
old.content,
'new_content',
new.content,
'old_timestamp',
old.timestamp,
'new_timestamp',
new.timestamp,
'old_player',
old.player,
'new_player',
new.player
)
);
end;
create trigger note_delete_audit
after delete on note begin
insert into audit_log (table_name, row_id, action, changes)
values (
'note',
old.id,
'DELETE',
json_object(
'content',
old.content,
'timestamp',
old.timestamp,
'player',
old.player
)
);
end;