Commit 1d565a88 by Owo Sugiana

Tambah Log Table sebagai backup

1 parent 13fdd952
0.3 29-12-2020
--------------
- Helper untuk memasang pencatatan perubahan isi tabel.
0.2 24-12-2020
--------------
- Jumlah backup bisa diatur di konfigurasi
......
include *.txt *.rst *.py
recursive-include maintenance *.py
recursive-include log_table *.py *.sql
......@@ -72,4 +72,25 @@ dilakukan. Contohnya di ``/etc/cron.d/maintenance`` berikut ini::
MAILTO=""
45 1 * * * root cd /home/sugiana/2020/08 && env/bin/maintenance maintenance.ini >/dev/null 2>&1
Log Table
---------
Ini merupakan bagian dari skenario backup dimana setiap perubahan record akan
dicatat di tabel `log_table` baik saat INSERT, UPDATE, maupun DELETE. Bekerja
menggunakan trigger di setiap tabel yang akan dicatat.
Buatlah file konfigurasi `live.ini`::
[main]
db_url = postgresql://user:pass@localhost/db
Buat tabel beserta fungsi trigger::
$ ~/env/bin/log_table_init_db live.ini
Tetapkanlah tabel yang akan dicatat perubahannya. Utamanya tabel terkait transaksi dan *user profile*::
$ ~/env/bin/log_table_trigger live.ini --schema=pbb --table=pembayaran_sppt
Semoga berhasil.
File mode changed
CREATE OR REPLACE FUNCTION rec_to_json(p_table_schema name, p_table_name name, p_rec record) RETURNS json LANGUAGE plpgsql AS $$
DECLARE
v_val text;
v_one json;
v_all json;
v_field record;
BEGIN
FOR v_field IN
SELECT column_name
FROM information_schema.columns
WHERE table_schema = p_table_schema
AND table_name = p_table_name
LOOP
EXECUTE format('SELECT (($1).%I)::text', v_field.column_name)
USING p_rec
INTO v_val;
v_one = json_build_object(v_field.column_name, v_val);
IF v_all IS NULL THEN
v_all = v_one;
ELSE
v_all = v_all::jsonb || v_one::jsonb;
END IF;
END LOOP;
RETURN v_all;
END
$$
CREATE OR REPLACE FUNCTION log_table_after_delete() RETURNS trigger LANGUAGE plpgsql AS $$
DECLARE
v_old json;
BEGIN
v_old = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, OLD);
INSERT INTO log_table (table_schema, table_name, operation, old_values)
VALUES (TG_TABLE_SCHEMA, TG_TABLE_NAME, 'delete', v_old);
RETURN NEW;
END
$$
CREATE OR REPLACE FUNCTION log_table_after_insert() RETURNS trigger LANGUAGE plpgsql AS $$
DECLARE
v_new json;
BEGIN
v_new = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, NEW);
INSERT INTO log_table (table_schema, table_name, operation, new_values)
VALUES (TG_TABLE_SCHEMA, TG_TABLE_NAME, 'insert', v_new);
RETURN NEW;
END
$$
CREATE OR REPLACE FUNCTION log_table_after_update() RETURNS trigger LANGUAGE plpgsql AS $$
DECLARE
v_old json;
v_new json;
BEGIN
v_old = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, OLD);
v_new = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, NEW);
INSERT INTO log_table (table_schema, table_name, operation, old_values, new_values)
VALUES (TG_TABLE_SCHEMA, TG_TABLE_NAME, 'update', v_old, v_new);
RETURN NEW;
END
$$
import sys
import os
from configparser import ConfigParser
from sqlalchemy import engine_from_config
from sqlalchemy.sql.expression import text
from .models import Base
t = os.path.split(__file__)
current_dir = t[0]
def execute(engine, filename):
fullpath = os.path.join(current_dir, filename)
with open(fullpath) as f:
sql = f.read()
engine.execute(text(sql))
def main(argv=sys.argv[1:]):
conf_file = argv[0]
conf = ConfigParser()
conf.read(conf_file)
engine = engine_from_config(conf['main'], 'db_')
engine.echo = True
Base.metadata.create_all(engine)
execute(engine, 'func-rec-to-json.sql')
for operation in ('insert', 'update', 'delete'):
filename = f'func-trigger-after-{operation}.sql'
execute(engine, filename)
from sqlalchemy import (
Column,
Integer,
String,
DateTime,
JSON,
CheckConstraint,
func,
)
from sqlalchemy.ext.declarative import declarative_base
Base = declarative_base()
class Log(Base):
__tablename__ = 'log_table'
id = Column(Integer, primary_key=True)
created = Column(
DateTime(timezone=True), nullable=False,
server_default=func.now())
table_schema = Column(String(32))
table_name = Column(String(32), nullable=False)
operation = Column(
String(6),
CheckConstraint("operation IN ('insert', 'update', 'delete')"),
nullable=False)
old_values = Column(JSON)
new_values = Column(JSON)
sqlalchemy
psycopg2-binary
import sys
from configparser import ConfigParser
from argparse import ArgumentParser
from sqlalchemy import (
engine_from_config,
exc,
)
from sqlalchemy.sql.expression import text
def get_option(argv):
default_schema = 'public'
help_schema = 'default ' + default_schema
pars = ArgumentParser()
pars.add_argument('conf')
pars.add_argument('--table', required=True)
pars.add_argument('--schema', default=default_schema, help=help_schema)
return pars.parse_args(argv)
def main(argv=sys.argv[1:]):
option = get_option(argv)
conf_file = option.conf
conf = ConfigParser()
conf.read(conf_file)
engine = engine_from_config(conf['main'], 'db_')
engine.echo = True
table_name = option.table
table_schema = option.schema
for operation in ('insert', 'update', 'delete'):
trigger_name = f'log_table_{operation}'
sql = f'DROP TRIGGER {trigger_name} ON {table_name}'
try:
engine.execute(text(sql))
except exc.ProgrammingError as e:
s = str(e)
if s.find('does not exist') == -1:
raise e
sql = f'CREATE TRIGGER {trigger_name} '\
f'AFTER {operation} ON {table_name} '\
f'FOR EACH ROW EXECUTE PROCEDURE log_table_after_{operation}()'
engine.execute(text(sql))
......@@ -32,6 +32,8 @@ setup(
entry_points={
'console_scripts': [
'maintenance = maintenance:main',
'log_table_init_db = log_table.init_db:main',
'log_table_trigger = log_table.set_trigger:main',
]
},
)
Markdown is supported
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!