Commit 2a445676 by Owo Sugiana

Bug fixed pada log_table saat tabel ke-2

1 parent a5245c8c
0.8.2 14-3-2024
---------------
- Bug fixed pada log_table saat diterapkan pada tabel ke-2. Ini terkait cache
pada Postgres.
- Mengganti engine.execute() dengan conn.execute() sesuai SQLAlchemy yang baru.
0.8.1 21-5-2023
......
CREATE EXTENSION IF NOT EXISTS hstore;
CREATE OR REPLACE FUNCTION rec_to_json(p_table_schema name, p_table_name name, p_rec record) RETURNS json LANGUAGE plpgsql AS $$
CREATE OR REPLACE FUNCTION rec_to_json(p_table_schema name, p_table_name name, p_rec hstore) RETURNS json LANGUAGE plpgsql AS $$
DECLARE
v_val text;
v_one json;
......@@ -6,26 +6,15 @@ DECLARE
v_field record;
v_column text;
BEGIN
FOR v_field IN
SELECT column_name
FROM information_schema.columns
WHERE table_schema = p_table_schema
AND table_name = p_table_name
FOR v_column, v_val IN select key,value FROM each(p_rec)
LOOP
v_column = v_field.column_name;
EXECUTE format('SELECT (($1).%I)::text', v_column)
USING p_rec
INTO v_val;
v_one = json_build_object(v_field.column_name, v_val);
v_one = json_build_object(v_column, 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
$$
......@@ -2,11 +2,11 @@ CREATE OR REPLACE FUNCTION log_table_after_delete() RETURNS trigger LANGUAGE plp
DECLARE
v_old json;
BEGIN
v_old = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, OLD);
v_old = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, hstore(OLD));
INSERT INTO log_table (table_schema, table_name, operation, old_values)
VALUES (TG_TABLE_SCHEMA, TG_TABLE_NAME, 'delete', v_old);
RETURN NEW;
RETURN OLD;
END
$$
......@@ -2,7 +2,7 @@ CREATE OR REPLACE FUNCTION log_table_after_insert() RETURNS trigger LANGUAGE plp
DECLARE
v_new json;
BEGIN
v_new = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, NEW);
v_new = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, hstore(NEW));
INSERT INTO log_table (table_schema, table_name, operation, new_values)
VALUES (TG_TABLE_SCHEMA, TG_TABLE_NAME, 'insert', v_new);
......
......@@ -3,8 +3,8 @@ 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);
v_old = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, hstore(OLD));
v_new = rec_to_json(TG_TABLE_SCHEMA, TG_TABLE_NAME, hstore(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);
......
......@@ -14,7 +14,8 @@ def execute(engine, filename):
fullpath = os.path.join(current_dir, filename)
with open(fullpath) as f:
sql = f.read()
engine.execute(text(sql))
with engine.begin() as conn:
conn.execute(text(sql))
def main(argv=sys.argv[1:]):
......@@ -24,6 +25,7 @@ def main(argv=sys.argv[1:]):
engine = engine_from_config(conf['main'], 'db_')
engine.echo = True
Base.metadata.create_all(engine)
execute(engine, 'create-extension-hstore.sql')
execute(engine, 'func-rec-to-json.sql')
for operation in ('insert', 'update', 'delete'):
filename = f'func-trigger-after-{operation}.sql'
......
......@@ -33,7 +33,7 @@ def main(argv=sys.argv[1:]):
trigger_name = f'log_table_{operation}'
sql = f'DROP TRIGGER {trigger_name} ON {table_name}'
try:
with engine.connect() as conn:
with engine.begin() as conn:
conn.execute(text(sql))
except exc.ProgrammingError as e:
s = str(e)
......@@ -42,5 +42,5 @@ def main(argv=sys.argv[1:]):
sql = f'CREATE TRIGGER {trigger_name} '\
f'AFTER {operation} ON {table_name} '\
f'FOR EACH ROW EXECUTE PROCEDURE log_table_after_{operation}()'
with engine.connect() as conn:
with engine.begin() as conn:
conn.execute(text(sql))
Markdown is supported
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!