├── LICENSE ├── documentation ├── data-schema.png ├── documentation.html └── ru │ ├── data-schema-ru.png │ └── documentation-ru.html ├── example ├── example_at_timestamp.sql ├── example_changes.sql ├── example_changes_ui.sql ├── example_grants.sql ├── example_simple.sql ├── example_view_hist.sql └── ru │ └── example_simple_ru.sql ├── extension └── pghist_extension.tar ├── lang └── pghist_lang_ru.sql ├── pghist_drop.sql ├── pghist_grants.sql ├── pghist_init.sql └── readme.md /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2021 PGHist 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. -------------------------------------------------------------------------------- /documentation/data-schema.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/PGSuite/PGHist/3e6bed0422ec74e6aed579e99e2c618209716498/documentation/data-schema.png -------------------------------------------------------------------------------- /documentation/ru/data-schema-ru.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/PGSuite/PGHist/3e6bed0422ec74e6aed579e99e2c618209716498/documentation/ru/data-schema-ru.png -------------------------------------------------------------------------------- /example/example_at_timestamp.sql: -------------------------------------------------------------------------------- 1 | -- Create schema and tables, enable history 2 | drop schema if exists example cascade; 3 | create schema example; 4 | 5 | create table example.customer( 6 | id int primary key, 7 | name varchar(100) not null 8 | ); 9 | insert into example.customer values (1,'Horns'),(2,'Hooves'); 10 | 11 | create table example.document( 12 | id int primary key, 13 | number varchar(10), 14 | date date 15 | ); 16 | 17 | create table example.invoice( 18 | primary key (id), 19 | customer_id int references example.customer(id), 20 | amount numeric(20,2) 21 | ) inherits (example.document); 22 | create index on example.invoice(customer_id); 23 | 24 | call pghist.hist_enable('example', 'customer'); 25 | call pghist.hist_enable('example', 'document'); 26 | call pghist.hist_enable('example', 'invoice'); 27 | 28 | -- Enter data into tables 29 | insert into example.document values (11,'#10', current_date); 30 | insert into example.invoice values (12,'#20', current_date, 1, 120.00); 31 | insert into example.invoice values (13,'#30', current_date-1, 2, 130.00); 32 | 33 | -- Select data in past 34 | select * from example.document_at_timestamp(now()-interval '10 second'); 35 | 36 | -- Erroneous update and recovery 37 | update example.invoice set customer_id=2,amount=300 where date=current_date; 38 | 39 | update example.invoice i 40 | set amount = h.amount 41 | from example.invoice_at_timestamp('2024-04-06 10:00:00') h 42 | where i.id = h.id 43 | and i.date=current_date; 44 | 45 | -- Сombination log and versioning 46 | select * 47 | from example.invoice_at_timestamp('2024-04-06 10:00:00') 48 | where id in ( 49 | select id from example.invoice_hist 50 | where hist_timestamp>'2024-04-06 10:00:00' 51 | and hist_db_user=current_user 52 | ); 53 | 54 | -- Сomplex query in past 55 | select * 56 | from example.invoice i 57 | join example.customer c on c.id=i.customer_id; 58 | 59 | do $$ 60 | begin 61 | perform set_config('pghist.at_timestamp', '2024-04-06 10:00:00', true); 62 | perform example.invoice_at_timestamp(); 63 | perform example.customer_at_timestamp(); 64 | end; 65 | $$; 66 | 67 | select * 68 | from example_invoice_at_timestamp i 69 | join example_customer_at_timestamp c on c.id=i.customer_id; 70 | -------------------------------------------------------------------------------- /example/example_changes.sql: -------------------------------------------------------------------------------- 1 | -- Create schema and tables 2 | drop schema if exists example cascade; 3 | create schema example; 4 | 5 | create table example.customer( 6 | id int primary key, 7 | name varchar(100) not null 8 | ); 9 | insert into example.customer values (1,'Horns'),(2,'Hooves'); 10 | 11 | create table example.invoice( 12 | id int primary key, 13 | number varchar(10), 14 | date date, 15 | customer_id int references example.customer(id), 16 | amount numeric(20,2) 17 | ); 18 | comment on table example.invoice is 'Invoice'; 19 | comment on column example.invoice.id is 'Identifier'; 20 | comment on column example.invoice.number is 'Number'; 21 | comment on column example.invoice.date is 'Date'; 22 | comment on column example.invoice.customer_id is 'Сustomer'; 23 | comment on column example.invoice.amount is 'Amount'; 24 | 25 | create table example.product( 26 | id int primary key, 27 | name varchar(100) not null, 28 | code varchar(10) not null 29 | ); 30 | 31 | create table example.invoice_product( 32 | id serial primary key, 33 | invoice_id int references example.invoice(id), 34 | product_id int references example.product(id), 35 | quantity int, 36 | color char(1) check (color in ('R','G','B')) 37 | ); 38 | comment on table example.invoice_product is 'Product of invoice'; 39 | comment on column example.invoice_product.id is 'Identifier'; 40 | comment on column example.invoice_product.invoice_id is 'Invoice'; 41 | comment on column example.invoice_product.product_id is 'Product'; 42 | comment on column example.invoice_product.quantity is 'Quantity'; 43 | comment on column example.invoice_product.color is 'Color'; 44 | create index on example.invoice_product(invoice_id); 45 | 46 | -- Enable history 47 | call pghist.hist_enable('example', 'invoice'); 48 | call pghist.hist_enable('example', 'invoice_product', 'example', 'invoice'); 49 | 50 | -- Change data 51 | insert into example.invoice values (12,'#20', current_date, 1, 120.00); 52 | update example.invoice set customer_id=2 where id=12; 53 | insert into example.product(id,name,code) values (101,'Pensil','030'),(102,'Notebook','040'); 54 | insert into example.invoice_product(id, invoice_id, product_id, quantity, color) values (1,12,101,1000,'R'),(2,12,101,10,'G'); 55 | 56 | do $$ 57 | begin 58 | update example.invoice_product set quantity=quantity+1,color='B' where id=1; 59 | delete from example.invoice_product where id=2; 60 | update example.invoice set amount=150 where id=12; 61 | end; 62 | $$; 63 | 64 | -- Select all changes, first three columns provide chronological 65 | select * from example.invoice_changes() order by 1,2,3; 66 | 67 | -- Select all changes with column id (immutable), insert detail by columns, without detail table example.invoice_product 68 | select * from example.invoice_changes(hist_columns_insert=>true, hist_columns_immutable=>true, hist_tables_detail=>false) order by 1,2,3; 69 | 70 | -- Select partial changes by id with detail table, autocreated indexes provide fast execution 71 | select * from example.invoice_changes(12) order by 1,2,3; 72 | 73 | -- Equivalent with using union all 74 | select * from example.invoice_changes(id=>12, hist_tables_detail=>false) 75 | union all 76 | select * from example.invoice_product_changes(invoice_id=>12) 77 | order by 1,2,3; 78 | 79 | -- Set description expression for columns row_desc and value_desc 80 | call pghist.hist_expression_row_desc('example', 'invoice', '''Invoice'''); 81 | call pghist.hist_expression_row_desc('example', 'invoice_product', $$ 'Row #'||$1.id||' / '||(select name from example.product where id=$1.product_id) $$); 82 | call pghist.hist_expression_value_desc('example', 'invoice_product', 'color', $$ case when $1='R' then 'Red' when $1='B' then 'Blue' when $1='G' then 'Green' else $1 end $$); 83 | 84 | -- Replace function for column db_user_name 85 | create or replace function example.db_user_name(db_user name) returns varchar language plpgsql as $$ 86 | begin 87 | return '['||db_user||']'; 88 | end; $$; 89 | call pghist.hist_column_custom_function('db_user_name', 'example.db_user_name'); 90 | -- call pghist.hist_column_custom_function('db_user_name', 'pghist.hist_default_db_user_name'); 91 | 92 | -------------------------------------------------------------------------------- /example/example_changes_ui.sql: -------------------------------------------------------------------------------- 1 | -- Create function that returns changes by date 2 | create or replace function example.invoice_changes_ui_date(date_changes date) returns setof pghist.hist_table_change language sql security definer as $$ 3 | select c.* 4 | from (select distinct id from example.invoice_hist where hist_timestamp::date=date_changes) h 5 | cross join example.invoice_changes(h.id) c 6 | order by 1,2,3; 7 | $$; 8 | select * from example.invoice_changes_ui_date(current_date); 9 | 10 | -- Create function that returns changes to master and detail tables 11 | create or replace function example.invoice_changes_ui_simple(id int) returns setof pghist.hist_table_change language sql security definer as $$ 12 | select * from example.invoice_changes(id=>id,hist_tables_detail=>false,hist_columns_insert=>true) 13 | union all 14 | select * from example.invoice_product_changes(invoice_id=>id) 15 | order by 1,2,3; 16 | $$; 17 | select * from example.invoice_changes_ui_simple(12); 18 | 19 | -- Create type with only necessary columns for the UI and cast function to it, 20 | -- type is created only once (as a rule, there is only one history view form per project) 21 | create type example.hist_table_change_ui as ( 22 | timestamp timestamptz, 23 | operation_name varchar, 24 | db_user_name varchar, 25 | row_desc text, 26 | column_comment varchar, 27 | value_old_desc text, 28 | value_new_desc text 29 | ); 30 | create or replace function example.hist_table_change_ui_cast(c pghist.hist_table_change) returns example.hist_table_change_ui language plpgsql as $$ 31 | begin 32 | return (c.timestamp,c.operation_name,c.db_user_name,c.row_desc,c.column_comment,c.value_old_desc,c.value_new_desc)::example.hist_table_change_ui; 33 | end; $$; 34 | create cast(pghist.hist_table_change as example.hist_table_change_ui) with function example.hist_table_change_ui_cast as assignment; 35 | 36 | -- Create function that returns only necessary columns 37 | create or replace function example.invoice_changes_ui(id int) returns setof example.hist_table_change_ui language sql security definer as $$ 38 | select c::pghist.hist_table_change::example.hist_table_change_ui from ( 39 | select * from example.invoice_changes(id=>id,hist_tables_detail=>false,hist_columns_insert=>true) 40 | union all 41 | select * from example.invoice_product_changes(invoice_id=>id) 42 | order by 1,2,3 43 | ) c; 44 | $$; 45 | select * from example.invoice_changes_ui(12); 46 | 47 | -------------------------------------------------------------------------------- /example/example_grants.sql: -------------------------------------------------------------------------------- 1 | -- postgres grant privileges on pghist schema and pghist.hist_enable procedure to developer_1 2 | -- all privileges in pghist_grants.sql file 3 | grant usage on schema pghist to developer_1; 4 | grant execute on procedure pghist.hist_enable(name) to developer_1; 5 | 6 | 7 | -- developer_1 create table, enable history, grant privileges on example table and example_changes function to user_1 8 | create table example( 9 | id int primary key, 10 | name varchar(20), 11 | number numeric(10,2), 12 | date date 13 | ); 14 | 15 | call pghist.hist_enable('example'); 16 | 17 | grant select,insert,update on example to user_1; 18 | grant execute on function example_changes to user_1; 19 | 20 | 21 | -- user_1 change data and view changes 22 | insert into example values (1, 'Example', 10, current_date); 23 | update example set number=20, date=date-1; 24 | 25 | select * from example_changes() order by 1,2,3; 26 | 27 | -- When trying to select log, user_1 receives an error 28 | -- SQL Error [42501]: ERROR: permission denied for view example_hist 29 | select * from example_hist; -------------------------------------------------------------------------------- /example/example_simple.sql: -------------------------------------------------------------------------------- 1 | -- Create table 2 | create table example( 3 | id int primary key, 4 | name varchar(20), 5 | number numeric(10,2), 6 | date date 7 | ); 8 | 9 | -- Enable keeping history 10 | call pghist.hist_enable('example'); 11 | 12 | -- Change data 13 | insert into example values (1, 'Example', 10, current_date); 14 | update example set number=20, date=date-1; 15 | 16 | -- View change log by row 17 | select * from example_hist; 18 | 19 | -- View changes by field 20 | select * from example_changes() order by 1,2,3; 21 | 22 | -- View table at timestamp 23 | select * from example_at_timestamp(now()-interval '10 second'); 24 | 25 | -- drop table example cascade; -------------------------------------------------------------------------------- /example/example_view_hist.sql: -------------------------------------------------------------------------------- 1 | -- Create schema and table, enable history, change data 2 | drop schema if exists example cascade; 3 | create schema example; 4 | 5 | create table example.document( 6 | id int primary key, 7 | number varchar(10), 8 | amount numeric(10,2) 9 | ); 10 | 11 | call pghist.hist_enable('example', 'document'); 12 | 13 | insert into example.document values (11, '#10', 100); 14 | insert into example.document values (12, '#20', 200); 15 | update example.document set number='#20/2',amount=210 where id=12; 16 | update example.document set amount=220 where id=12; 17 | delete from example.document where id=11; 18 | 19 | -- Select full info 20 | select * from example.document_hist; 21 | 22 | -- Select partial info by id 23 | select hist_timestamp,hist_operation,hist_db_user,amount_old 24 | from example.document_hist 25 | where id=12 and (hist_operation!='UPDATE' or 'amount'=any(hist_update_columns)) 26 | order by hist_statement_id; 27 | 28 | -- Select partial info with current values 29 | select * from example.document_hist 30 | union all 31 | select null,null,null,'[CURRENT_VALUES]',null,null,null,null,null,null,* from example.document 32 | order by id,1; 33 | 34 | -- Create extended view and grant select on it to developer 35 | -- (alternatively to 'grant select on all tables in schema pghist to developer'); 36 | select * 37 | from pghist.hist_data$example_document h 38 | join pghist.hist_statement s on s.id = h.hist_statement_id 39 | join pghist.hist_query q on q.hash = s.query_hash 40 | join pghist.hist_transaction t on t.id = s.transaction_id 41 | order by h.hist_statement_id, h.id; 42 | 43 | create or replace view example.document_hist_ext as 44 | select h.id,t.timestamp_commit,t.db_client_addr,q.text query_text 45 | from pghist.hist_data$example_document h 46 | join pghist.hist_statement s on s.id = h.hist_statement_id 47 | join pghist.hist_query q on q.hash = s.query_hash 48 | join pghist.hist_transaction t on t.id = s.transaction_id 49 | order by h.hist_statement_id, h.id; 50 | 51 | select * from example.document_hist_ext where id=12; 52 | 53 | grant select on example.document_hist_ext to developer_1; 54 | 55 | -------------------------------------------------------------------------------- /example/ru/example_simple_ru.sql: -------------------------------------------------------------------------------- 1 | -- Создаем таблицу 2 | create table example( 3 | id int primary key, 4 | name varchar(20), 5 | number numeric(10,2), 6 | date date 7 | ); 8 | 9 | -- Включаем ведение истории 10 | call pghist.hist_enable('example'); 11 | 12 | -- Изменяем данные 13 | insert into example values (1, 'Пример', 10, current_date); 14 | update example set number=20, date=date-1; 15 | 16 | -- Получаем лог изменений по строкам 17 | select * from example_hist; 18 | 19 | -- Получаем изменения по полям 20 | select * from example_changes(); 21 | 22 | -- Получаем таблицу в прошлом 23 | select * from example_at_timestamp(now()-interval '10 second'); 24 | 25 | -- drop table example cascade; -------------------------------------------------------------------------------- /extension/pghist_extension.tar: -------------------------------------------------------------------------------- 1 | pghist.control0000644000000000000000000000023215006435662010650 0ustar comment = 'PGHist - History of table changes in PostgreSQL' 2 | default_version = '25.2' 3 | relocatable = false 4 | schema = 'pghist' 5 | requires = '' 6 | superuser = true 7 | pghist--25.2.sql0000644000000000000000000016365315006435662010451 0ustar \echo Use "CREATE EXTENSION pghist" to load this file. \quit 8 | -- This file is automatically created from the pghist_init.sql file. 9 | ; 10 | 11 | create or replace function pghist.pghist_version() returns varchar language plpgsql as $$ 12 | begin 13 | return '25.2'; 14 | end; $$; 15 | 16 | create table if not exists pghist.hist_transaction( 17 | id bigint primary key, 18 | xid bigint not null, 19 | timestamp_start timestamptz not null, 20 | timestamp_commit timestamptz, 21 | application_name varchar, 22 | backend_pid integer not null, 23 | backend_start timestamptz not null, 24 | db_user name not null, 25 | db_client_addr inet, 26 | db_client_hostname varchar, 27 | app_user name, 28 | app_client_addr inet, 29 | app_client_hostname varchar 30 | ) with (fillfactor=90); 31 | create sequence if not exists pghist.hist_transaction_seq as bigint increment 2; 32 | 33 | create table if not exists pghist.hist_query( 34 | hash bigint primary key, 35 | text text not null 36 | ); 37 | 38 | create table if not exists pghist.hist_statement( 39 | id bigint primary key, 40 | transaction_id bigint not null, -- references pghist.hist_transaction(id) on delete cascade, 41 | timestamp timestamptz not null, 42 | operation varchar(16) not null check (operation in ('HIST_ENABLE','INSERT','UPDATE','DELETE','TRUNCATE')), 43 | query_hash bigint not null -- references pghist.hist_query(hash) 44 | ); 45 | create sequence if not exists pghist.hist_statement_seq as bigint increment 2; 46 | 47 | create table if not exists pghist.hist_table( 48 | schema name, 49 | name name, 50 | primary key (schema,name), 51 | pkey name[] not null, 52 | master_table_schema name, 53 | master_table_name name, 54 | master_table_fkey name[], 55 | columns_excluded name[] not null, 56 | expression_row_desc varchar 57 | ); 58 | 59 | create table if not exists pghist.hist_table_column( 60 | schema name, 61 | table_name name, 62 | foreign key (schema,table_name) references pghist.hist_table on delete cascade, 63 | column_name name, 64 | primary key (schema,table_name,column_name), 65 | expression_value_desc varchar 66 | ); 67 | 68 | create table if not exists pghist.hist_sql_log( 69 | id serial primary key, 70 | pghist_version varchar(8) not null default pghist.pghist_version(), 71 | transaction_id bigint not null references pghist.hist_transaction(id) on delete cascade, 72 | schema name not null, 73 | table_name name not null, 74 | sql_statement text not null 75 | ); 76 | 77 | do $$ begin 78 | if to_regtype('pghist.hist_table_change') is null then 79 | create type pghist.hist_table_change as ( 80 | statement_num bigint, 81 | row_num int, 82 | column_num int, 83 | timestamp timestamptz, 84 | operation varchar, 85 | operation_name varchar, 86 | column_name name, 87 | column_comment varchar, 88 | value_old text, 89 | value_old_desc text, 90 | value_new text, 91 | value_new_desc text, 92 | row_desc text, 93 | db_user name, 94 | db_user_name varchar, 95 | app_user varchar, 96 | app_user_name varchar, 97 | schema name, 98 | table_name name, 99 | table_comment text 100 | ); 101 | end if; 102 | end $$; 103 | 104 | create or replace function pghist.hist_transaction_fn_commit() returns trigger security definer language plpgsql as $$ 105 | begin 106 | update pghist.hist_transaction set timestamp_commit = clock_timestamp() where id=new.id; 107 | return null; 108 | end; $$; 109 | 110 | do $$ begin 111 | if not exists (select from pg_trigger where tgrelid='pghist.hist_transaction'::regclass::oid and tgname='hist_transaction_tg_commit') then 112 | create constraint trigger hist_transaction_tg_commit after insert on pghist.hist_transaction deferrable initially deferred for each row execute procedure pghist.hist_transaction_fn_commit(); 113 | end if; 114 | end $$; 115 | 116 | create or replace function pghist.hist_statement_id(operation varchar) returns bigint language plpgsql as $$ 117 | declare 118 | v_id bigint := reverse(nextval('pghist.hist_statement_seq')::varchar); 119 | v_transaction_id bigint = pghist.hist_transaction_id(); 120 | v_query_text text = current_query(); 121 | v_query_hash bigint := hashtextextended(v_query_text, 0); 122 | begin 123 | insert into pghist.hist_query(hash, text) values (v_query_hash, v_query_text) on conflict (hash) do nothing; 124 | insert into pghist.hist_statement(id, transaction_id, timestamp, operation, query_hash) 125 | values (v_id, v_transaction_id, clock_timestamp(), operation, v_query_hash); 126 | return v_id; 127 | end; $$; 128 | 129 | create or replace procedure pghist.hist_execute_sql(schema name, table_name name, sql_statement varchar) language plpgsql as $$ 130 | begin 131 | execute sql_statement; 132 | insert into pghist.hist_sql_log(transaction_id,schema,table_name,sql_statement) 133 | values(pghist.hist_transaction_id(),schema,table_name,sql_statement); 134 | end; $$; 135 | 136 | create or replace function pghist.hist_ident(ident name) returns name language plpgsql as $$ 137 | begin 138 | return case when left(ident,1)='"' then ident else lower(ident) end; 139 | end; $$; 140 | 141 | create or replace function pghist.hist_ident(prefix varchar, ident name, suffix varchar) returns name language plpgsql as $$ 142 | begin 143 | return case when left(ident,1)='"' then '"'||prefix||substr(ident,2,length(ident)-2)||suffix||'"' else prefix||lower(ident)||suffix end; 144 | end; $$; 145 | 146 | create or replace function pghist.hist_ident_in_str(ident text) returns name language plpgsql as $$ 147 | begin 148 | return replace(ident,'''',''''''); 149 | end; $$; 150 | 151 | create or replace function pghist.hist_ident_table(prefix varchar, schema name, table_name name) returns varchar language plpgsql as $$ 152 | begin 153 | if left(schema,1)!='"' and left(table_name,1)!='"' then 154 | return prefix||schema||'_'||table_name; 155 | end if; 156 | return 157 | '"' || prefix || case when left(schema,1)='"' then substr(schema,2,length(schema)-2) else schema end || 158 | '_' || case when left(table_name,1)='"' then substr(table_name,2,length(table_name)-2) else table_name end || '"'; 159 | end; $$; 160 | 161 | create or replace procedure pghist.hist_objects_name(schema name, table_name name, inout hist_data_table name, inout hist_data_func_prefix name, inout trigger_prefix name, inout view_hist name, inout func_changes name, inout func_at_timestamp name) language plpgsql as $$ 162 | begin 163 | hist_data_table := pghist.hist_ident_table('hist_data$', schema, table_name); 164 | hist_data_func_prefix := pghist.hist_ident('', hist_data_table, '$'); 165 | hist_data_table := 'pghist.'||hist_data_table; 166 | -- 167 | trigger_prefix := pghist.hist_ident('hist_', table_name, '_tg_'); 168 | view_hist := pghist.hist_ident('', table_name, '_hist'); 169 | func_changes := pghist.hist_ident('', table_name, '_changes'); 170 | func_at_timestamp := pghist.hist_ident('', table_name, '_at_timestamp'); 171 | end; $$; 172 | 173 | create or replace function pghist.hist_exists(schema name, table_name name) returns boolean language plpgsql as $$ 174 | declare 175 | v_schema name := pghist.hist_ident(schema); 176 | v_table_name name := pghist.hist_ident(table_name); 177 | begin 178 | return exists (select from pghist.hist_table where hist_table.schema=v_schema and hist_table.name=v_table_name); 179 | end; $$; 180 | 181 | create or replace function pghist.hist_columns_to_text(columns name[], expr text default 'col', delimiter varchar default ',') returns varchar language plpgsql as $$ 182 | declare 183 | v_text text; 184 | begin 185 | if pg_catalog.array_length(columns, 1) is null then return ''; end if; 186 | execute format('select string_agg(%s, ''%s'' order by pos) from unnest($1) with ordinality r(col,pos)', expr, delimiter ) 187 | into v_text 188 | using columns; 189 | return v_text; 190 | end; $$; 191 | 192 | create or replace procedure pghist.hist_table_columns(table_oid oid, columns_excluded name[], inout columns_name name[], inout columns_type name[], inout columns_comment varchar[]) language plpgsql as $$ 193 | begin 194 | select array_agg(quote_ident(attname) order by attnum), 195 | array_agg(case when tn.nspname!='pg_catalog' then quote_ident(tn.nspname)||'.' else '' end || quote_ident(typname) order by attnum), 196 | array_agg(coalesce(quote_literal(col_description(attrelid,attnum)),'null') order by attnum) 197 | into columns_name, columns_type, columns_comment 198 | from pg_attribute a 199 | join pg_type t on t.oid=a.atttypid 200 | join pg_namespace tn on tn.oid=t.typnamespace 201 | where attrelid=table_oid and attnum>0 and not attisdropped and not quote_ident(attname)=any(columns_excluded); 202 | end; $$; 203 | 204 | create or replace function pghist.hist_master_table_fkey(table_oid oid, master_table_schema name, master_table_name name) returns name[] language plpgsql as $$ 205 | declare 206 | v_fkey_out int[]; 207 | v_fkey_in int[]; 208 | v_master_pkey int[]; 209 | v_master_table_oid oid; 210 | v_master_table_fkey name[]; 211 | begin 212 | if master_table_schema is null then 213 | return null; 214 | end if; 215 | v_master_table_oid := (master_table_schema||'.'||master_table_name)::regclass::oid; 216 | select d.conkey,d.confkey,m.conkey master_pkey 217 | into v_fkey_out,v_fkey_in,v_master_pkey 218 | from pg_constraint d 219 | join pg_constraint m on m.conrelid=d.confrelid and m.contype='p' 220 | where d.contype='f' and d.conrelid=table_oid and d.confrelid=v_master_table_oid 221 | order by d.conkey[1] 222 | limit 1; 223 | if v_fkey_out is null then 224 | raise exception 'PGSUITE-2003 Not found foreign key on master table'; 225 | end if; 226 | return ( 227 | select array_agg(quote_ident(a.attname) order by master_pkey.pos) 228 | from unnest(v_master_pkey) with ordinality master_pkey(num,pos) 229 | join pg_attribute a on a.attrelid=table_oid and a.attnum=v_fkey_out[array_position(v_fkey_in, master_pkey.num)] 230 | ); 231 | end; $$; 232 | 233 | create or replace function pghist.hist_columns_immutable(pkey name[], master_table_fkey name[]) returns name[] language plpgsql as $$ 234 | declare 235 | v_columns_immutable name[] := pkey; 236 | v_col name; 237 | begin 238 | if master_table_fkey is not null then 239 | foreach v_col in array master_table_fkey loop 240 | if not v_col=any(pkey) then 241 | v_columns_immutable := v_columns_immutable||v_col; 242 | end if; 243 | end loop; 244 | end if; 245 | return v_columns_immutable; 246 | end; $$; 247 | 248 | create or replace procedure pghist.hist_enable(schema name, table_name name, master_table_schema name default null, master_table_name name default null, columns_excluded name[] default null) security definer language plpgsql as $$ 249 | declare 250 | v_schema name := pghist.hist_ident(schema); 251 | v_table_name name := pghist.hist_ident(table_name); 252 | v_table_oid oid := (v_schema||'.'||v_table_name)::regclass::oid; 253 | v_master_table_schema name := pghist.hist_ident(master_table_schema); 254 | v_master_table_name name := pghist.hist_ident(master_table_name); 255 | v_master_table_fkey name[] := pghist.hist_master_table_fkey(v_table_oid, v_master_table_schema, v_master_table_name); 256 | v_columns_excluded name[] := coalesce((select array_agg(pghist.hist_ident(ce)) from unnest(columns_excluded) ce), array[]::name[]); 257 | v_columns_name name[]; 258 | v_columns_type name[]; 259 | v_columns_comment varchar[]; 260 | v_columns_pkey name[]; 261 | v_columns_immutable name[]; 262 | -- 263 | v_hist_data_table name; 264 | v_hist_data_func_prefix name; 265 | v_trigger_prefix name; 266 | v_view_hist name; 267 | v_func_changes name; 268 | v_func_at_timestamp name; 269 | -- 270 | v_sql text; 271 | v_col name; 272 | v_operation varchar; 273 | v_newline char := E'\n'; 274 | begin 275 | if pghist.hist_exists(v_schema,v_table_name) then 276 | perform pghist.hist_objects_refresh(v_schema,v_table_name); 277 | return; 278 | end if; 279 | call pghist.hist_objects_name(v_schema, v_table_name, v_hist_data_table, v_hist_data_func_prefix, v_trigger_prefix, v_view_hist, v_func_changes, v_func_at_timestamp); 280 | call pghist.hist_table_columns(v_table_oid, v_columns_excluded, v_columns_name, v_columns_type, v_columns_comment); 281 | select array_agg(quote_ident(attname) order by col_pos) 282 | into v_columns_pkey 283 | from unnest( (select conkey from pg_constraint where conrelid=v_table_oid and contype='p') ) with ordinality c(col_num,col_pos) 284 | join pg_attribute a on attrelid=v_table_oid and attnum = col_num; 285 | if v_columns_pkey is null then 286 | raise exception 'PGSUITE-2002 Table does not have primary key'; 287 | end if; 288 | v_columns_immutable := pghist.hist_columns_immutable(v_columns_pkey, v_master_table_fkey); 289 | v_sql := 290 | 'create table '||v_hist_data_table||' ('||v_newline|| 291 | ' hist_statement_id bigint not null, -- references pghist.hist_statement(id) on delete cascade,'||v_newline|| 292 | ' hist_row_num int not null,'||v_newline|| 293 | ' hist_update_columns name[],'||v_newline; 294 | foreach v_col in array v_columns_immutable loop 295 | v_sql := v_sql||' '||v_col||' '||v_columns_type[array_position(v_columns_name,v_col)]||' not null,'||v_newline; 296 | end loop; 297 | foreach v_col in array v_columns_name loop 298 | if not v_col=any(v_columns_immutable) then 299 | v_sql := v_sql||' '||pghist.hist_ident('',v_col,'_old')||' '||v_columns_type[array_position(v_columns_name,v_col)]||','||v_newline; 300 | end if; 301 | end loop; 302 | v_sql := v_sql|| 303 | ' primary key ('||pghist.hist_columns_to_text(v_columns_pkey)||',hist_statement_id)'||v_newline|| 304 | ')'; 305 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 306 | call pghist.hist_execute_sql(v_schema, v_table_name, 'lock table '||v_hist_data_table||' in exclusive mode'); 307 | v_sql := 308 | 'insert into '||v_hist_data_table||' (hist_statement_id,hist_row_num,'||pghist.hist_columns_to_text(v_columns_immutable)||')'||v_newline|| 309 | ' select '||pghist.hist_statement_id('HIST_ENABLE')||',row_number() over (),'||pghist.hist_columns_to_text(v_columns_immutable)||' from only '||v_schema||'.'||v_table_name; 310 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 311 | if v_master_table_fkey is not null then 312 | call pghist.hist_execute_sql(v_schema, v_table_name, 'create index on '||v_hist_data_table||'('||pghist.hist_columns_to_text(v_master_table_fkey)||')'); 313 | end if; 314 | insert into pghist.hist_table(schema,name,pkey,master_table_schema,master_table_name,master_table_fkey,columns_excluded) 315 | values (v_schema,v_table_name,v_columns_pkey,v_master_table_schema,v_master_table_name,v_master_table_fkey,v_columns_excluded); 316 | perform pghist.hist_objects_refresh(v_schema, v_table_name); 317 | foreach v_operation in array array['insert','update','delete','truncate'] loop 318 | v_sql := 319 | 'create trigger '||pghist.hist_ident('',v_trigger_prefix,v_operation)|| 320 | ' '||case when v_operation='truncate' then 'before' else 'after' end||' '||v_operation|| 321 | ' on '||v_schema||'.'||v_table_name|| 322 | case when v_operation='truncate' then '' else ' referencing' end|| 323 | case when v_operation in ('insert','update') then ' new table as rows_new' else '' end|| 324 | case when v_operation in ('update','delete') then ' old table as rows_old' else '' end|| 325 | case when v_operation='truncate' then '' else ' for each statement' end|| 326 | ' execute procedure pghist.'||pghist.hist_ident('',v_hist_data_func_prefix,v_operation)||'();'; 327 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 328 | end loop; 329 | if v_master_table_schema is not null then 330 | perform pghist.hist_objects_refresh(v_master_table_schema, v_master_table_name); 331 | end if; 332 | end; $$; 333 | 334 | create or replace procedure pghist.hist_enable(table_name name) security definer language plpgsql as $$ 335 | declare 336 | v_schema name; 337 | v_table_name name; 338 | begin 339 | select quote_ident(n.nspname),quote_ident(c.relname) 340 | into v_schema,v_table_name 341 | from pg_class c 342 | join pg_namespace n on n.oid=c.relnamespace 343 | where c.oid=table_name::regclass::oid; 344 | call pghist.hist_enable(v_schema, v_table_name); 345 | end; $$; 346 | 347 | create or replace procedure pghist.hist_parent_refresh(schema name, table_name name) language plpgsql as $$ 348 | declare 349 | v_parent_schema name; 350 | v_parent_table_name name; 351 | begin 352 | select quote_ident(quote_ident(c.relnamespace::regnamespace::name)),quote_ident(c.relname) 353 | into v_parent_schema,v_parent_table_name 354 | from pg_inherits i 355 | join pg_class c on c.oid=i.inhparent 356 | where i.inhrelid=(select oid from pg_class where quote_ident(relnamespace::regnamespace::name)=schema and quote_ident(relname)=table_name); 357 | if v_parent_schema is not null then 358 | perform pghist.hist_objects_refresh(v_parent_schema,v_parent_table_name); 359 | end if; 360 | end; $$; 361 | 362 | create or replace procedure pghist.hist_disable(schema name, table_name name) security definer language plpgsql as $$ 363 | declare 364 | v_schema name := pghist.hist_ident(schema); 365 | v_table_name name := pghist.hist_ident(table_name); 366 | v_table_oid oid := to_regclass(v_schema||'.'||v_table_name)::oid; 367 | v_master_table_schema name; 368 | v_master_table_name name; 369 | v_hist_data_table name; 370 | v_hist_data_func_prefix name; 371 | v_trigger_prefix name; 372 | v_view_hist name; 373 | v_func_changes name; 374 | v_func_at_timestamp name; 375 | v_operation varchar; 376 | begin 377 | select v_master_table_schema,master_table_name 378 | into v_master_table_schema,v_master_table_name 379 | from pghist.hist_table ht 380 | where ht.schema=v_schema and ht.name=v_table_name; 381 | call pghist.hist_objects_name(v_schema, v_table_name, v_hist_data_table, v_hist_data_func_prefix, v_trigger_prefix, v_view_hist, v_func_changes, v_func_at_timestamp); 382 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop view if exists '||v_schema||'.'||v_view_hist); 383 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop function if exists '||v_schema||'.'||v_func_changes); 384 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop function if exists '||v_schema||'.'||v_func_at_timestamp); 385 | foreach v_operation in array array['insert','update','delete','truncate'] loop 386 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop function if exists pghist.'||pghist.hist_ident('',v_hist_data_func_prefix,v_operation)||' cascade'); 387 | end loop; 388 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop table if exists '||v_hist_data_table||' cascade'); 389 | delete from pghist.hist_table where hist_table.schema=v_schema and hist_table.name=v_table_name; 390 | call pghist.hist_parent_refresh(v_schema, v_table_name); 391 | if v_master_table_schema is not null then 392 | perform pghist.hist_objects_refresh(v_master_table_schema, v_master_table_name); 393 | end if; 394 | end; $$; 395 | 396 | create or replace procedure pghist.hist_disable(table_name name) security definer language plpgsql as $$ 397 | declare 398 | v_schema name; 399 | v_table_name name; 400 | begin 401 | select quote_ident(n.nspname),quote_ident(c.relname) 402 | into v_schema,v_table_name 403 | from pg_class c 404 | join pg_namespace n on n.oid=c.relnamespace 405 | where c.oid=table_name::regclass::oid; 406 | call pghist.hist_disable(v_schema, v_table_name); 407 | end; $$; 408 | 409 | create or replace function pghist.hist_event_column_rename(schema name, table_name name, table_oid oid, column_name_old name, column_num int) returns void security definer language plpgsql as $$ 410 | declare 411 | v_schema name := pghist.hist_ident(schema); 412 | v_table_name name := pghist.hist_ident(table_name); 413 | v_column_name_old name := quote_ident(column_name_old); 414 | v_column_name_new name := quote_ident((select attname from pg_attribute where attrelid=table_oid and attnum=column_num)); 415 | v_hist_column_name_old name := pghist.hist_ident('',v_column_name_old,'_old'); 416 | -- 417 | v_hist_data_table name; 418 | v_hist_data_func_prefix name; 419 | v_trigger_prefix name; 420 | v_view_hist name; 421 | v_func_changes name; 422 | v_func_at_timestamp name; 423 | begin 424 | if v_column_name_old is null or v_column_name_new is null or v_column_name_old=v_column_name_new then 425 | return; 426 | end if; 427 | call pghist.hist_objects_name(v_schema, v_table_name, v_hist_data_table, v_hist_data_func_prefix, v_trigger_prefix, v_view_hist, v_func_changes, v_func_at_timestamp); 428 | if not exists (select from pg_attribute where attrelid=v_hist_data_table::regclass::oid and quote_ident(attname)=v_hist_column_name_old) then 429 | return; 430 | end if; 431 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop view if exists '||v_schema||'.'||v_view_hist); 432 | call pghist.hist_execute_sql(v_schema, v_table_name, 'alter table '||v_hist_data_table||' rename column '||v_hist_column_name_old||' to '||pghist.hist_ident('',v_column_name_new,'_old')); 433 | call pghist.hist_execute_sql(v_schema, v_table_name, 'update '||v_hist_data_table||' set hist_update_columns=array_replace(hist_update_columns,'||quote_literal(v_column_name_old)||','||quote_literal(v_column_name_new)||') where '||quote_literal(v_column_name_old)||'=any(hist_update_columns)'); 434 | end; 435 | $$; 436 | 437 | create or replace function pghist.hist_event_ddl_command() returns event_trigger stable security definer language plpgsql as $$ 438 | declare 439 | v_table record; 440 | begin 441 | for v_table in 442 | select t.schema,t.name 443 | from pg_event_trigger_ddl_commands() e 444 | join pg_class c on c.oid=e.objid 445 | join pghist.hist_table t on t.schema=quote_ident(e.schema_name) and t.name=quote_ident(c.relname) 446 | where e.object_type='table' 447 | loop 448 | perform pghist.hist_objects_refresh(v_table.schema, v_table.name); 449 | end loop; 450 | for v_table in 451 | select t.schema,t.name,e.objid oid,a.attname column_name_old,e.objsubid column_num 452 | from pg_event_trigger_ddl_commands() e 453 | join pg_class c on c.oid=e.objid 454 | join pg_attribute a on a.attrelid=e.objid and a.attnum=e.objsubid 455 | join pghist.hist_table t on t.schema=quote_ident(e.schema_name) and t.name=quote_ident(c.relname) 456 | where e.object_type='table column' 457 | loop 458 | perform pghist.hist_event_column_rename(v_table.schema, v_table.name, v_table.oid, v_table.column_name_old, v_table.column_num); 459 | perform pghist.hist_objects_refresh(v_table.schema, v_table.name); 460 | end loop; 461 | for v_table in 462 | select t.schema,t.name 463 | from pg_event_trigger_ddl_commands() e 464 | join pg_index i on i.indexrelid=e.objid 465 | join pg_class c on c.oid=i.indrelid 466 | join pghist.hist_table t on t.schema=quote_ident(e.schema_name) and t.name=quote_ident(c.relname) 467 | where e.object_type='index' 468 | loop 469 | perform pghist.hist_objects_refresh(v_table.schema, v_table.name); 470 | end loop; 471 | end; 472 | $$; 473 | 474 | create or replace function pghist.hist_event_drop_table() returns event_trigger security definer language plpgsql as $$ 475 | declare 476 | v_table record; 477 | begin 478 | for v_table in 479 | select t.schema,t.name 480 | from pg_event_trigger_dropped_objects() o 481 | join pghist.hist_table t on o.object_type='table' and t.schema=quote_ident(o.schema_name) and t.name=quote_ident(o.object_name) 482 | loop 483 | call pghist.hist_disable(v_table.schema, v_table.name); 484 | end loop; 485 | end; 486 | $$; 487 | 488 | do $$ begin 489 | if not exists (select 1 from pg_event_trigger where evtname='pghist_event_tg_ddl_command') then 490 | create event trigger pghist_event_tg_ddl_command on ddl_command_end when tag in ('ALTER TABLE','CREATE INDEX','COMMENT') execute procedure pghist.hist_event_ddl_command(); 491 | end if; 492 | if not exists (select 1 from pg_event_trigger where evtname='pghist_event_tg_drop_table') then 493 | create event trigger pghist_event_tg_drop_table on sql_drop when tag in ('DROP TABLE','DROP SCHEMA') execute function pghist.hist_event_drop_table(); 494 | end if; 495 | end $$; 496 | 497 | 498 | create or replace function pghist.hist_objects_refresh(schema name, table_name name) returns void security definer language plpgsql as $body$ 499 | declare 500 | v_schema name := pghist.hist_ident(schema); 501 | v_table_name name := pghist.hist_ident(table_name); 502 | v_table_oid oid := (v_schema||'.'||v_table_name)::regclass::oid; 503 | v_table_comment varchar := coalesce(quote_literal(col_description(v_table_oid, 0)),'null'); 504 | v_table_owner name := (select relowner::regrole::name from pg_class where oid=v_table_oid); 505 | v_tables_inherited name[][]; 506 | v_columns_name name[]; 507 | v_columns_type name[]; 508 | v_columns_pkey name[]; 509 | v_columns_comment varchar[]; 510 | v_columns_immutable name[]; 511 | v_columns_excluded name[]; 512 | v_columns_value name[]; 513 | v_columns_value_old name[]; 514 | v_columns_expr_value_new_desc varchar[]; 515 | v_columns_expr_value_old_desc varchar[]; 516 | v_row_desc_expr varchar; 517 | -- 518 | v_hist_data_table name; 519 | v_hist_data_func_prefix name; 520 | v_trigger_prefix name; 521 | v_view_hist name; 522 | v_func_changes name; 523 | v_func_at_timestamp name; 524 | -- 525 | v_sql text; 526 | v_sql_part text; 527 | v_sql_condition text; 528 | v_sql_hist_to_row text; 529 | v_sql_hist_data_func name; 530 | v_col name; 531 | v_operation varchar; 532 | v_expression varchar; 533 | v_type_convert varchar; 534 | v_temp_table_at_timestamp name; 535 | v_i int; 536 | v_rec record; 537 | v_newline char := E'\n'; 538 | begin 539 | call pghist.hist_objects_name(v_schema, v_table_name, v_hist_data_table, v_hist_data_func_prefix, v_trigger_prefix, v_view_hist, v_func_changes, v_func_at_timestamp); 540 | select ht.pkey,pghist.hist_columns_immutable(ht.pkey,ht.master_table_fkey),ht.columns_excluded 541 | into v_columns_pkey,v_columns_immutable,v_columns_excluded 542 | from pghist.hist_table ht 543 | where ht.schema=v_schema and ht.name=v_table_name; 544 | call pghist.hist_table_columns(v_table_oid, v_columns_excluded, v_columns_name, v_columns_type, v_columns_comment); 545 | select array_agg(array[child_schema,child_table_name] order by child_schema,child_table_name) 546 | into v_tables_inherited 547 | from ( 548 | select quote_ident(n.nspname) child_schema, quote_ident(c.relname) child_table_name 549 | from pg_inherits i 550 | join pg_class c on c.oid=i.inhrelid 551 | join pg_namespace n on n.oid=c.relnamespace 552 | where i.inhparent = v_table_oid 553 | ) c 554 | join pghist.hist_table t on t.schema=child_schema and t.name=child_table_name; 555 | -- 556 | for v_rec in 557 | select quote_ident(substring(attname,1,length(attname)-4)) column_name, quote_ident(attname) column_name_old 558 | from pg_attribute 559 | where attrelid=v_hist_data_table::regclass::oid and not quote_ident(attname)=any(v_columns_immutable) and attnum>3 and not attisdropped 560 | and (quote_ident(attname),atttypid) not in ( 561 | select pghist.hist_ident('',quote_ident(attname),'_old'),atttypid from pg_attribute where attrelid=v_table_oid and attnum>0 and not attisdropped and not quote_ident(attname)=any(v_columns_excluded) 562 | ) 563 | loop 564 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop view if exists '||v_schema||'.'||v_view_hist); 565 | call pghist.hist_execute_sql(v_schema, v_table_name, 'alter table '||v_hist_data_table||' drop column '||v_rec.column_name_old); 566 | call pghist.hist_execute_sql(v_schema, v_table_name, 'update '||v_hist_data_table||' set hist_update_columns=array_remove(hist_update_columns,'||quote_literal(v_rec.column_name)||') where '||quote_literal(v_rec.column_name)||'=any(hist_update_columns)'); 567 | end loop; 568 | for v_rec in 569 | select quote_ident(attname) column_name, typname column_type, pg_get_expr(d.adbin,d.adrelid) default_value 570 | from pg_attribute a 571 | join pg_type t on t.oid=a.atttypid 572 | left join pg_attrdef d on d.adrelid=a.attrelid and d.adnum=a.attnum 573 | where attrelid=v_table_oid and not quote_ident(attname)=any(v_columns_immutable) and attnum>0 and not attisdropped and not quote_ident(attname)=any(v_columns_excluded) 574 | and pghist.hist_ident('',quote_ident(attname),'_old') not in (select quote_ident(attname) from pg_attribute where attrelid=v_hist_data_table::regclass::oid and attnum>0 and not attisdropped) 575 | order by attnum 576 | loop 577 | call pghist.hist_execute_sql(v_schema, v_table_name, 'alter table '||v_hist_data_table||' add column '||pghist.hist_ident('',v_rec.column_name,'_old')||' '||v_rec.column_type); 578 | if v_rec.default_value is not null then 579 | call pghist.hist_execute_sql(v_schema, v_table_name, 'lock table '||v_hist_data_table||' in exclusive mode'); 580 | v_sql := 581 | 'insert into '||v_hist_data_table||' (hist_statement_id,hist_row_num,hist_update_columns,'||pghist.hist_columns_to_text(v_columns_immutable)||')'||v_newline|| 582 | ' select '||pghist.hist_statement_id('UPDATE')||',row_number() over (),array['||pg_catalog.quote_literal(v_rec.column_name)||'],'||pghist.hist_columns_to_text(v_columns_immutable)||' from only '||v_schema||'.'||v_table_name; 583 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 584 | end if; 585 | end loop; 586 | select array_agg(col),array_agg(pghist.hist_ident('',col,'_old')) into v_columns_value,v_columns_value_old from unnest(v_columns_name) col where not col = any(v_columns_immutable); 587 | for v_i in 1..array_length(v_columns_name,1) loop 588 | v_expression := pghist.hist_expression_value_desc_current(v_schema, v_table_name, v_columns_name[v_i]); 589 | if v_expression is not null then 590 | v_sql_part := ' execute '||quote_literal('select ('||v_expression||')')||' into v_change.value_'; 591 | v_columns_expr_value_new_desc[v_i] := v_sql_part||'new_desc using v_row.'||v_columns_name[v_i]||';'; 592 | v_columns_expr_value_old_desc[v_i] := v_sql_part||'old_desc using v_row.'||v_columns_name[v_i]||';'; 593 | else 594 | v_columns_expr_value_new_desc[v_i] := ' v_change.value_new_desc := v_change.value_new;'; 595 | v_columns_expr_value_old_desc[v_i] := ' v_change.value_old_desc := v_change.value_old;'; 596 | end if; 597 | end loop; 598 | v_row_desc_expr := 'execute '||quote_literal('select ('||pghist.hist_expression_row_desc_current(v_schema, v_table_name)||')')||' into v_change.row_desc using v_row;'; 599 | -- 600 | v_sql_hist_data_func := 'pghist.'||pghist.hist_ident('',v_hist_data_func_prefix,'insert'); 601 | v_sql := 602 | 'create or replace function '||v_sql_hist_data_func||'() returns trigger language plpgsql security definer as $$'||v_newline|| 603 | 'declare '||v_newline|| 604 | ' v_statement_id bigint = pghist.hist_statement_id(tg_op);'||v_newline|| 605 | 'begin '||v_newline|| 606 | ' insert into '||v_hist_data_table||'(hist_statement_id,hist_row_num,'||pghist.hist_columns_to_text(v_columns_immutable)||')'||v_newline|| 607 | ' select v_statement_id,row_number() over (),'||pghist.hist_columns_to_text(v_columns_immutable)||v_newline|| 608 | ' from rows_new;'||v_newline|| 609 | ' return null;'||v_newline|| 610 | 'end;'||v_newline|| 611 | '$$'; 612 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 613 | call pghist.hist_execute_sql(v_schema, v_table_name, 'grant execute on function '||v_sql_hist_data_func||' to '||v_table_owner); 614 | v_sql_hist_data_func := 'pghist.'||pghist.hist_ident('',v_hist_data_func_prefix,'update'); 615 | v_sql := 616 | 'create or replace function '||v_sql_hist_data_func||'() returns trigger language plpgsql security definer as $$'||v_newline|| 617 | 'declare '||v_newline|| 618 | ' v_statement_id bigint = pghist.hist_statement_id(tg_op);'||v_newline|| 619 | 'begin '||v_newline|| 620 | ' if exists ('||v_newline|| 621 | ' select from rows_old o'||v_newline|| 622 | ' left join rows_new n on '||pghist.hist_columns_to_text(v_columns_immutable,$$ 'o.'||col||'=n.'||col $$,' and ')||v_newline|| 623 | ' where n.'||v_columns_pkey[1]||' is null'||v_newline|| 624 | ' ) then '||v_newline|| 625 | ' raise exception ''PGSUITE-2001 Update column(s) '||pghist.hist_columns_to_text(v_columns_immutable,$$ pghist.hist_ident_in_str(col) $$)||' of table '||pghist.hist_ident_in_str(v_schema)||'.'||pghist.hist_ident_in_str(v_table_name)||' is not allowed'';'||v_newline|| 626 | ' end if;'||v_newline|| 627 | ' insert into '||v_hist_data_table||'(hist_statement_id,hist_row_num,hist_update_columns,'||pghist.hist_columns_to_text(v_columns_immutable)||pghist.hist_columns_to_text(v_columns_value_old,$$ ','||col $$,'')||')'||v_newline|| 628 | ' select v_statement_id,'||v_newline|| 629 | ' hist_row_num,'||v_newline|| 630 | ' array[]::name[]'||v_newline; 631 | v_sql_part := pghist.hist_columns_to_text(v_columns_immutable,$$ ' o.'||col||',' $$,v_newline)||v_newline; 632 | for v_i in 1..array_length(v_columns_value,1) loop 633 | v_col := v_columns_value[v_i]; 634 | v_type_convert := case when v_columns_type[array_position(v_columns_name, v_col)] in ('json','_json','xml','_xml') then '::text' else '' end; 635 | v_sql_condition := '(o.'||v_col||v_type_convert||'!=n.'||v_col||v_type_convert||') or (o.'||v_col||' is null and n.'||v_col||' is not null) or (o.'||v_col||' is not null and n.'||v_col||' is null)'; 636 | v_sql := v_sql||' ||(case when '||v_sql_condition||' then '||quote_literal(v_col)||'::name end)'||case when v_i=array_length(v_columns_value,1) then ',' else '' end||v_newline; 637 | v_sql_part := v_sql_part||' case when '||v_sql_condition||' then o.'||v_col||' end'||case when v_i=transaction_timestamp'||v_newline|| 846 | ' union all'||v_newline|| 847 | ' select null,null,null,'||pghist.hist_columns_to_text(v_columns_immutable)||pghist.hist_columns_to_text(v_columns_value,$$ ','||col $$,'')||v_newline|| 848 | ' from only '||v_schema||'.'||v_table_name||v_newline|| 849 | ' order by '||pghist.hist_columns_to_text(v_columns_pkey)||',hist_statement_id desc;'||v_newline|| 850 | ' v_column name;'||v_newline|| 851 | 'begin'||v_newline|| 852 | ' drop table if exists '||v_temp_table_at_timestamp||';'||v_newline|| 853 | ' create temp table '||v_temp_table_at_timestamp||' as select * from '||v_schema||'.'||v_table_name||' limit 0;'||v_newline|| 854 | ' open v_cur_hist;'||v_newline|| 855 | ' loop'||v_newline|| 856 | ' fetch v_cur_hist into v_hist;'||v_newline|| 857 | ' v_hist_not_found := not found;'||v_newline|| 858 | ' if (v_hist_not_found and v_row.'||v_columns_pkey[1]||' is not null) or ('||pghist.hist_columns_to_text(v_columns_pkey,$$ 'v_row.'||col||'!=v_hist.'||col $$,' or ')||') then'||v_newline|| 859 | ' insert into '||v_temp_table_at_timestamp||' values (v_row.*);'||v_newline|| 860 | ' v_row := null;'||v_newline|| 861 | ' end if;'||v_newline|| 862 | ' exit when v_hist_not_found;'||v_newline|| 863 | ' if v_hist.hist_operation is null or v_hist.hist_operation in (''DELETE'',''TRUNCATE'') then'||v_newline|| 864 | ' '||v_sql_hist_to_row||v_newline|| 865 | ' continue;'||v_newline|| 866 | ' end if;'||v_newline|| 867 | ' if v_hist.hist_operation = ''UPDATE'' then'||v_newline|| 868 | ' foreach v_column in array v_hist.hist_update_columns loop'||v_newline; 869 | foreach v_col in array v_columns_value loop 870 | v_sql := v_sql|| 871 | ' if v_column='||quote_literal(v_col)||' then v_row.'||v_col||':=v_hist.'||pghist.hist_ident('',v_col,'_old')||'; continue; end if;'||v_newline; 872 | end loop; 873 | v_sql := v_sql|| 874 | ' end loop;'||v_newline|| 875 | ' continue;'||v_newline|| 876 | ' end if;'||v_newline|| 877 | ' if v_hist.hist_operation in (''INSERT'',''HIST_ENABLE'') then'||v_newline|| 878 | ' v_row := null;'||v_newline|| 879 | ' continue;'||v_newline|| 880 | ' end if;'||v_newline|| 881 | ' end loop;'||v_newline|| 882 | ' close v_cur_hist;'||v_newline; 883 | if v_tables_inherited is not null then 884 | v_sql := v_sql||' if tables_inherited then'||v_newline; 885 | for v_i in 1..array_length(v_tables_inherited, 1) loop 886 | v_sql := v_sql|| 887 | ' insert into '||v_temp_table_at_timestamp||v_newline|| 888 | ' select '||pghist.hist_columns_to_text(v_columns_name)||v_newline|| 889 | ' from '||v_tables_inherited[v_i][1]||'.'||pghist.hist_ident('',v_tables_inherited[v_i][2],'_at_timestamp')||'(transaction_timestamp, tables_inherited);'||v_newline; 890 | end loop; 891 | v_sql := v_sql||' end if;'||v_newline; 892 | end if; 893 | select 894 | string_agg( 895 | ' create index on '||v_temp_table_at_timestamp||' ('|| 896 | (select string_agg(quote_ident(attname), ',' order by col_pos) 897 | from unnest(indkey) with ordinality col(col_num,col_pos) 898 | join pg_attribute on attrelid=indrelid and attnum=col_num 899 | )|| 900 | '); -- '||relname||v_newline 901 | , '' order by relname) 902 | into v_sql_part 903 | from pg_index 904 | join pg_class on pg_class.oid=indexrelid 905 | where indrelid=v_table_oid and 0!=any(indkey); 906 | v_sql := v_sql||v_sql_part|| 907 | ' for v_row in (select * from '||v_temp_table_at_timestamp||') loop'||v_newline|| 908 | ' return next v_row;'||v_newline|| 909 | ' end loop;'||v_newline|| 910 | 'end;'||v_newline|| 911 | '$func$'; 912 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 913 | call pghist.hist_execute_sql(v_schema, v_table_name, 'grant execute on function '||v_schema||'.'||v_func_at_timestamp||' to '||v_table_owner||' with grant option'); 914 | -- 915 | call pghist.hist_parent_refresh(v_schema, v_table_name); 916 | end; $body$; 917 | 918 | 919 | create or replace procedure pghist.hist_expression_row_desc(schema name, table_name name, expression varchar) language plpgsql as $$ 920 | declare 921 | v_schema name := pghist.hist_ident(schema); 922 | v_table_name name := pghist.hist_ident(table_name); 923 | begin 924 | update pghist.hist_table ht set expression_row_desc=expression where ht.schema=v_schema and ht.name=v_table_name; 925 | call pghist.hist_enable(schema, table_name); 926 | end; $$; 927 | 928 | create or replace function pghist.hist_expression_row_desc_default(schema name, table_name name) returns varchar language plpgsql as $$ 929 | declare 930 | v_table_oid oid := (pghist.hist_ident(schema)||'.'||pghist.hist_ident(table_name))::regclass::oid; 931 | begin 932 | return ( 933 | select quote_literal(coalesce(col_description(v_table_oid, 0), table_name)||' #')||'||'||string_agg('$1.'||quote_ident(attname), '||'',''||' order by col_pos) expr 934 | from unnest( (select conkey from pg_constraint where conrelid=v_table_oid and contype='p') ) with ordinality c(col_num,col_pos) 935 | join pg_attribute a on attrelid=v_table_oid and attnum = col_num 936 | ); 937 | end; $$; 938 | 939 | create or replace function pghist.hist_expression_row_desc_current(schema name, table_name name) returns varchar language plpgsql as $$ 940 | declare 941 | v_schema name := pghist.hist_ident(schema); 942 | v_table_name name := pghist.hist_ident(table_name); 943 | begin 944 | return (select coalesce(expression_row_desc,pghist.hist_expression_row_desc_default(ht.schema,ht.name)) from pghist.hist_table ht where ht.schema=v_schema and ht.name=v_table_name); 945 | end; $$; 946 | 947 | create or replace procedure pghist.hist_expression_value_desc(schema name, table_name name, column_name name, expression varchar) language plpgsql as $$ 948 | declare 949 | v_schema name := pghist.hist_ident(schema); 950 | v_table_name name := pghist.hist_ident(table_name); 951 | v_column_name name := pghist.hist_ident(column_name); 952 | begin 953 | insert into pghist.hist_table_column(schema,table_name,column_name,expression_value_desc) 954 | values (v_schema,v_table_name,v_column_name,expression) 955 | on conflict on constraint hist_table_column_pkey do 956 | update set expression_value_desc = expression; 957 | call pghist.hist_enable(v_schema, v_table_name); 958 | end; $$; 959 | 960 | create or replace function pghist.hist_expression_value_desc_default(schema name, table_name name, column_name name) returns varchar language plpgsql as $$ 961 | declare 962 | v_table_oid oid := (pghist.hist_ident(schema)||'.'||pghist.hist_ident(table_name))::regclass::oid; 963 | v_column_name name := pghist.hist_ident(column_name); 964 | begin 965 | return ( 966 | select 'select '||quote_ident(f_text.attname)||' from '||quote_ident(f_nsp.nspname)||'.'||quote_ident(f_tab.relname)||' where '||quote_ident(f_key.attname)||'=$1' 967 | from pg_constraint c 968 | join pg_attribute ca on ca.attrelid=c.conrelid and ca.attnum=c.conkey[1] and quote_ident(ca.attname)=v_column_name 969 | join pg_class f_tab on f_tab.oid=c.confrelid 970 | join pg_namespace f_nsp on f_nsp.oid=f_tab.relnamespace 971 | join pg_attribute f_key on f_key.attrelid=c.confrelid and f_key.attnum=c.confkey[1] 972 | join pg_attribute f_text on f_text.attrelid=c.confrelid and f_text.attnum!=f_key.attnum 973 | join pg_type t on t.oid=f_text.atttypid and t.typcategory='S' 974 | where c.conrelid=v_table_oid and c.contype='f' and array_length(c.conkey,1)=1 975 | order by f_text.attnum 976 | limit 1 977 | ); 978 | end; $$; 979 | 980 | create or replace function pghist.hist_expression_value_desc_current(schema name, table_name name, column_name name) returns varchar language plpgsql as $$ 981 | declare 982 | v_schema name := pghist.hist_ident(schema); 983 | v_table_name name := pghist.hist_ident(table_name); 984 | v_column_name name := pghist.hist_ident(column_name); 985 | begin 986 | return coalesce( 987 | (select expression_value_desc from pghist.hist_table_column htc where htc.schema=v_schema and htc.table_name=v_table_name and htc.column_name=v_column_name), 988 | pghist.hist_expression_value_desc_default(v_schema, v_table_name, v_column_name) 989 | ); 990 | end; $$; 991 | 992 | create or replace function pghist.hist_default_operation_name(operation varchar) returns varchar language plpgsql as $$ 993 | begin 994 | return case 995 | when operation = 'HIST_ENABLE' then 'History start' 996 | when operation = 'INSERT' then 'Creation' 997 | when operation = 'UPDATE' then 'Modification' 998 | when operation = 'DELETE' then 'Deletion' 999 | when operation = 'TRUNCATE' then 'Cleaning' 1000 | end; 1001 | end; $$; 1002 | 1003 | create or replace function pghist.hist_default_db_user_name(db_user name) returns varchar language plpgsql as $$ begin return db_user; end; $$; 1004 | create or replace function pghist.hist_default_app_user() returns varchar language plpgsql as $$ begin return current_setting('app.user', true); end; $$; 1005 | create or replace function pghist.hist_default_app_user_name(app_user name) returns varchar language plpgsql as $$ begin return app_user; end; $$; 1006 | create or replace function pghist.hist_default_app_client_addr() returns inet language plpgsql as $$ begin return current_setting('app.client_addr', true)::inet; end; $$; 1007 | create or replace function pghist.hist_default_app_client_hostname() returns varchar language plpgsql as $$ begin return current_setting('app.client_hostname', true); end; $$; 1008 | 1009 | create table if not exists pghist.hist_column_custom_function( 1010 | column_name name primary key check (column_name in ('operation_name','db_user_name','app_user','app_user_name','app_client_addr','app_client_hostname')), 1011 | custom_function name not null 1012 | ); 1013 | 1014 | create or replace function pghist.hist_column_custom_function_current(column_name name) returns varchar language plpgsql as $$ 1015 | declare 1016 | v_column_name name := column_name; 1017 | begin 1018 | return coalesce((select custom_function from pghist.hist_column_custom_function f where f.column_name=v_column_name), 'pghist.hist_default_'||v_column_name); 1019 | end; $$; 1020 | 1021 | create or replace procedure pghist.hist_column_custom_function(column_name name, custom_function name) language plpgsql as $$ 1022 | declare 1023 | v_custom_function name := custom_function; 1024 | v_rec_table record; 1025 | begin 1026 | insert into pghist.hist_column_custom_function 1027 | values (column_name, v_custom_function) 1028 | on conflict on constraint hist_column_custom_function_pkey do 1029 | update set custom_function = v_custom_function; 1030 | if column_name in ('app_user','app_client_addr','app_client_hostname') then 1031 | call pghist.hist_create_function_transaction_id(); 1032 | else 1033 | for v_rec_table in 1034 | select schema,name from pghist.hist_table 1035 | loop 1036 | call pghist.hist_enable(v_rec_table.schema, v_rec_table.name); 1037 | end loop; 1038 | end if; 1039 | end; $$; 1040 | 1041 | create or replace procedure pghist.hist_create_function_transaction_id() security definer language plpgsql as $body$ 1042 | begin 1043 | execute $$ 1044 | 1045 | create or replace function pghist.hist_transaction_id() returns bigint language plpgsql as $func$ 1046 | declare 1047 | v_id_text varchar; 1048 | v_id bigint; 1049 | begin 1050 | v_id_text := current_setting('pghist.transaction_id', true); 1051 | if v_id_text!='' then 1052 | return v_id_text::bigint; 1053 | end if; 1054 | v_id := reverse(nextval('pghist.hist_transaction_seq')::varchar); 1055 | insert into pghist.hist_transaction(id, xid, timestamp_start, application_name, backend_pid, backend_start, db_user, db_client_addr, db_client_hostname, app_user, app_client_addr, app_client_hostname) 1056 | select v_id, txid_current(), xact_start, application_name, pg_backend_pid(), backend_start, usename, client_addr, client_hostname, $$ 1057 | || pghist.hist_column_custom_function_current('app_user') || '(), ' || pghist.hist_column_custom_function_current('app_client_addr') || '(), ' || pghist.hist_column_custom_function_current('app_client_hostname') || '()' || $$ 1058 | from pg_stat_activity p where pid = pg_backend_pid(); 1059 | perform set_config('pghist.transaction_id', v_id::varchar, true); 1060 | return v_id; 1061 | end; $func$; 1062 | 1063 | $$; 1064 | end; $body$; 1065 | 1066 | call pghist.hist_create_function_transaction_id(); 1067 | 1068 | 1069 | do $$ 1070 | declare 1071 | obj varchar; 1072 | begin 1073 | foreach obj in array 1074 | array['hist_transaction','hist_transaction_seq', 1075 | 'hist_query', 1076 | 'hist_statement','hist_statement_seq', 1077 | 'hist_table', 1078 | 'hist_table_column', 1079 | 'hist_column_custom_function'] 1080 | loop 1081 | perform pg_extension_config_dump(obj,''); 1082 | end loop; 1083 | end 1084 | $$; 1085 | -------------------------------------------------------------------------------- /lang/pghist_lang_ru.sql: -------------------------------------------------------------------------------- 1 | set client_encoding = 'UTF8'; 2 | 3 | create or replace function pghist.hist_lang_ru$operation_name(operation varchar) returns varchar language plpgsql as $$ 4 | begin 5 | return case 6 | when operation = 'HIST_ENABLE' then 'Включение истории' 7 | when operation = 'INSERT' then 'Создание' 8 | when operation = 'UPDATE' then 'Изменение' 9 | when operation = 'DELETE' then 'Удаление' 10 | when operation = 'TRUNCATE' then 'Очистка' 11 | end; 12 | end; $$; 13 | 14 | call pghist.hist_column_custom_function('operation_name', 'pghist.hist_lang_ru$operation_name'); 15 | 16 | -------------------------------------------------------------------------------- /pghist_drop.sql: -------------------------------------------------------------------------------- 1 | do $$ 2 | declare 3 | v_rec record; 4 | begin 5 | if to_regnamespace('pghist') is null then 6 | return; 7 | end if; 8 | for v_rec in 9 | select schema,name from pghist.hist_table 10 | loop 11 | call pghist.hist_disable(v_rec.schema,v_rec.name); 12 | end loop; 13 | end; $$; 14 | 15 | drop extension if exists pghist; 16 | 17 | drop event trigger if exists pghist_event_tg_ddl_command; 18 | drop event trigger if exists pghist_event_tg_drop_table; 19 | 20 | drop schema if exists pghist cascade; 21 | 22 | -------------------------------------------------------------------------------- /pghist_grants.sql: -------------------------------------------------------------------------------- 1 | grant usage on schema pghist to :roles; 2 | 3 | grant execute on procedure pghist.hist_enable(name,name,name,name,name[]),pghist.hist_enable(name) to :roles; 4 | grant execute on procedure pghist.hist_disable(name,name), pghist.hist_disable(name) to :roles; 5 | 6 | grant execute on procedure pghist.hist_expression_row_desc to :roles; 7 | grant execute on function pghist.hist_expression_row_desc_default to :roles; 8 | grant execute on function pghist.hist_expression_row_desc_current to :roles; 9 | 10 | grant execute on procedure pghist.hist_expression_value_desc to :roles; 11 | grant execute on function pghist.hist_expression_value_desc_default to :roles; 12 | grant execute on function pghist.hist_expression_value_desc_current to :roles; 13 | 14 | grant all on function pghist.hist_custom_operation_name to :roles; 15 | grant all on function pghist.hist_custom_db_user_name to :roles; 16 | grant all on function pghist.hist_custom_app_user to :roles; 17 | grant all on function pghist.hist_custom_app_user_name to :roles; 18 | grant all on function pghist.hist_custom_client_addr to :roles; 19 | grant all on function pghist.hist_custom_client_hostname to :roles; 20 | 21 | -------------------------------------------------------------------------------- /pghist_init.sql: -------------------------------------------------------------------------------- 1 | create schema if not exists pghist; 2 | 3 | create or replace function pghist.pghist_version() returns varchar language plpgsql as $$ 4 | begin 5 | return '25.2'; 6 | end; $$; 7 | 8 | create table if not exists pghist.hist_transaction( 9 | id bigint primary key, 10 | xid bigint not null, 11 | timestamp_start timestamptz not null, 12 | timestamp_commit timestamptz, 13 | application_name varchar, 14 | backend_pid integer not null, 15 | backend_start timestamptz not null, 16 | db_user name not null, 17 | db_client_addr inet, 18 | db_client_hostname varchar, 19 | app_user name, 20 | app_client_addr inet, 21 | app_client_hostname varchar 22 | ) with (fillfactor=90); 23 | create sequence if not exists pghist.hist_transaction_seq as bigint increment 2; 24 | 25 | create table if not exists pghist.hist_query( 26 | hash bigint primary key, 27 | text text not null 28 | ); 29 | 30 | create table if not exists pghist.hist_statement( 31 | id bigint primary key, 32 | transaction_id bigint not null, -- references pghist.hist_transaction(id) on delete cascade, 33 | timestamp timestamptz not null, 34 | operation varchar(16) not null check (operation in ('HIST_ENABLE','INSERT','UPDATE','DELETE','TRUNCATE')), 35 | query_hash bigint not null -- references pghist.hist_query(hash) 36 | ); 37 | create sequence if not exists pghist.hist_statement_seq as bigint increment 2; 38 | 39 | create table if not exists pghist.hist_table( 40 | schema name, 41 | name name, 42 | primary key (schema,name), 43 | pkey name[] not null, 44 | master_table_schema name, 45 | master_table_name name, 46 | master_table_fkey name[], 47 | columns_excluded name[] not null, 48 | expression_row_desc varchar 49 | ); 50 | 51 | create table if not exists pghist.hist_table_column( 52 | schema name, 53 | table_name name, 54 | foreign key (schema,table_name) references pghist.hist_table on delete cascade, 55 | column_name name, 56 | primary key (schema,table_name,column_name), 57 | expression_value_desc varchar 58 | ); 59 | 60 | create table if not exists pghist.hist_sql_log( 61 | id serial primary key, 62 | pghist_version varchar(8) not null default pghist.pghist_version(), 63 | transaction_id bigint not null references pghist.hist_transaction(id) on delete cascade, 64 | schema name not null, 65 | table_name name not null, 66 | sql_statement text not null 67 | ); 68 | 69 | do $$ begin 70 | if to_regtype('pghist.hist_table_change') is null then 71 | create type pghist.hist_table_change as ( 72 | statement_num bigint, 73 | row_num int, 74 | column_num int, 75 | timestamp timestamptz, 76 | operation varchar, 77 | operation_name varchar, 78 | column_name name, 79 | column_comment varchar, 80 | value_old text, 81 | value_old_desc text, 82 | value_new text, 83 | value_new_desc text, 84 | row_desc text, 85 | db_user name, 86 | db_user_name varchar, 87 | app_user varchar, 88 | app_user_name varchar, 89 | schema name, 90 | table_name name, 91 | table_comment text 92 | ); 93 | end if; 94 | end $$; 95 | 96 | create or replace function pghist.hist_transaction_fn_commit() returns trigger security definer language plpgsql as $$ 97 | begin 98 | update pghist.hist_transaction set timestamp_commit = clock_timestamp() where id=new.id; 99 | return null; 100 | end; $$; 101 | 102 | do $$ begin 103 | if not exists (select from pg_trigger where tgrelid='pghist.hist_transaction'::regclass::oid and tgname='hist_transaction_tg_commit') then 104 | create constraint trigger hist_transaction_tg_commit after insert on pghist.hist_transaction deferrable initially deferred for each row execute procedure pghist.hist_transaction_fn_commit(); 105 | end if; 106 | end $$; 107 | 108 | create or replace function pghist.hist_statement_id(operation varchar) returns bigint language plpgsql as $$ 109 | declare 110 | v_id bigint := reverse(nextval('pghist.hist_statement_seq')::varchar); 111 | v_transaction_id bigint = pghist.hist_transaction_id(); 112 | v_query_text text = current_query(); 113 | v_query_hash bigint := hashtextextended(v_query_text, 0); 114 | begin 115 | insert into pghist.hist_query(hash, text) values (v_query_hash, v_query_text) on conflict (hash) do nothing; 116 | insert into pghist.hist_statement(id, transaction_id, timestamp, operation, query_hash) 117 | values (v_id, v_transaction_id, clock_timestamp(), operation, v_query_hash); 118 | return v_id; 119 | end; $$; 120 | 121 | create or replace procedure pghist.hist_execute_sql(schema name, table_name name, sql_statement varchar) language plpgsql as $$ 122 | begin 123 | execute sql_statement; 124 | insert into pghist.hist_sql_log(transaction_id,schema,table_name,sql_statement) 125 | values(pghist.hist_transaction_id(),schema,table_name,sql_statement); 126 | end; $$; 127 | 128 | create or replace function pghist.hist_ident(ident name) returns name language plpgsql as $$ 129 | begin 130 | return case when left(ident,1)='"' then ident else lower(ident) end; 131 | end; $$; 132 | 133 | create or replace function pghist.hist_ident(prefix varchar, ident name, suffix varchar) returns name language plpgsql as $$ 134 | begin 135 | return case when left(ident,1)='"' then '"'||prefix||substr(ident,2,length(ident)-2)||suffix||'"' else prefix||lower(ident)||suffix end; 136 | end; $$; 137 | 138 | create or replace function pghist.hist_ident_in_str(ident text) returns name language plpgsql as $$ 139 | begin 140 | return replace(ident,'''',''''''); 141 | end; $$; 142 | 143 | create or replace function pghist.hist_ident_table(prefix varchar, schema name, table_name name) returns varchar language plpgsql as $$ 144 | begin 145 | if left(schema,1)!='"' and left(table_name,1)!='"' then 146 | return prefix||schema||'_'||table_name; 147 | end if; 148 | return 149 | '"' || prefix || case when left(schema,1)='"' then substr(schema,2,length(schema)-2) else schema end || 150 | '_' || case when left(table_name,1)='"' then substr(table_name,2,length(table_name)-2) else table_name end || '"'; 151 | end; $$; 152 | 153 | create or replace procedure pghist.hist_objects_name(schema name, table_name name, inout hist_data_table name, inout hist_data_func_prefix name, inout trigger_prefix name, inout view_hist name, inout func_changes name, inout func_at_timestamp name) language plpgsql as $$ 154 | begin 155 | hist_data_table := pghist.hist_ident_table('hist_data$', schema, table_name); 156 | hist_data_func_prefix := pghist.hist_ident('', hist_data_table, '$'); 157 | hist_data_table := 'pghist.'||hist_data_table; 158 | -- 159 | trigger_prefix := pghist.hist_ident('hist_', table_name, '_tg_'); 160 | view_hist := pghist.hist_ident('', table_name, '_hist'); 161 | func_changes := pghist.hist_ident('', table_name, '_changes'); 162 | func_at_timestamp := pghist.hist_ident('', table_name, '_at_timestamp'); 163 | end; $$; 164 | 165 | create or replace function pghist.hist_exists(schema name, table_name name) returns boolean language plpgsql as $$ 166 | declare 167 | v_schema name := pghist.hist_ident(schema); 168 | v_table_name name := pghist.hist_ident(table_name); 169 | begin 170 | return exists (select from pghist.hist_table where hist_table.schema=v_schema and hist_table.name=v_table_name); 171 | end; $$; 172 | 173 | create or replace function pghist.hist_columns_to_text(columns name[], expr text default 'col', delimiter varchar default ',') returns varchar language plpgsql as $$ 174 | declare 175 | v_text text; 176 | begin 177 | if pg_catalog.array_length(columns, 1) is null then return ''; end if; 178 | execute format('select string_agg(%s, ''%s'' order by pos) from unnest($1) with ordinality r(col,pos)', expr, delimiter ) 179 | into v_text 180 | using columns; 181 | return v_text; 182 | end; $$; 183 | 184 | create or replace procedure pghist.hist_table_columns(table_oid oid, columns_excluded name[], inout columns_name name[], inout columns_type name[], inout columns_comment varchar[]) language plpgsql as $$ 185 | begin 186 | select array_agg(quote_ident(attname) order by attnum), 187 | array_agg(case when tn.nspname!='pg_catalog' then quote_ident(tn.nspname)||'.' else '' end || quote_ident(typname) order by attnum), 188 | array_agg(coalesce(quote_literal(col_description(attrelid,attnum)),'null') order by attnum) 189 | into columns_name, columns_type, columns_comment 190 | from pg_attribute a 191 | join pg_type t on t.oid=a.atttypid 192 | join pg_namespace tn on tn.oid=t.typnamespace 193 | where attrelid=table_oid and attnum>0 and not attisdropped and not quote_ident(attname)=any(columns_excluded); 194 | end; $$; 195 | 196 | create or replace function pghist.hist_master_table_fkey(table_oid oid, master_table_schema name, master_table_name name) returns name[] language plpgsql as $$ 197 | declare 198 | v_fkey_out int[]; 199 | v_fkey_in int[]; 200 | v_master_pkey int[]; 201 | v_master_table_oid oid; 202 | v_master_table_fkey name[]; 203 | begin 204 | if master_table_schema is null then 205 | return null; 206 | end if; 207 | v_master_table_oid := (master_table_schema||'.'||master_table_name)::regclass::oid; 208 | select d.conkey,d.confkey,m.conkey master_pkey 209 | into v_fkey_out,v_fkey_in,v_master_pkey 210 | from pg_constraint d 211 | join pg_constraint m on m.conrelid=d.confrelid and m.contype='p' 212 | where d.contype='f' and d.conrelid=table_oid and d.confrelid=v_master_table_oid 213 | order by d.conkey[1] 214 | limit 1; 215 | if v_fkey_out is null then 216 | raise exception 'PGSUITE-2003 Not found foreign key on master table'; 217 | end if; 218 | return ( 219 | select array_agg(quote_ident(a.attname) order by master_pkey.pos) 220 | from unnest(v_master_pkey) with ordinality master_pkey(num,pos) 221 | join pg_attribute a on a.attrelid=table_oid and a.attnum=v_fkey_out[array_position(v_fkey_in, master_pkey.num)] 222 | ); 223 | end; $$; 224 | 225 | create or replace function pghist.hist_columns_immutable(pkey name[], master_table_fkey name[]) returns name[] language plpgsql as $$ 226 | declare 227 | v_columns_immutable name[] := pkey; 228 | v_col name; 229 | begin 230 | if master_table_fkey is not null then 231 | foreach v_col in array master_table_fkey loop 232 | if not v_col=any(pkey) then 233 | v_columns_immutable := v_columns_immutable||v_col; 234 | end if; 235 | end loop; 236 | end if; 237 | return v_columns_immutable; 238 | end; $$; 239 | 240 | create or replace procedure pghist.hist_enable(schema name, table_name name, master_table_schema name default null, master_table_name name default null, columns_excluded name[] default null) security definer language plpgsql as $$ 241 | declare 242 | v_schema name := pghist.hist_ident(schema); 243 | v_table_name name := pghist.hist_ident(table_name); 244 | v_table_oid oid := (v_schema||'.'||v_table_name)::regclass::oid; 245 | v_master_table_schema name := pghist.hist_ident(master_table_schema); 246 | v_master_table_name name := pghist.hist_ident(master_table_name); 247 | v_master_table_fkey name[] := pghist.hist_master_table_fkey(v_table_oid, v_master_table_schema, v_master_table_name); 248 | v_columns_excluded name[] := coalesce((select array_agg(pghist.hist_ident(ce)) from unnest(columns_excluded) ce), array[]::name[]); 249 | v_columns_name name[]; 250 | v_columns_type name[]; 251 | v_columns_comment varchar[]; 252 | v_columns_pkey name[]; 253 | v_columns_immutable name[]; 254 | -- 255 | v_hist_data_table name; 256 | v_hist_data_func_prefix name; 257 | v_trigger_prefix name; 258 | v_view_hist name; 259 | v_func_changes name; 260 | v_func_at_timestamp name; 261 | -- 262 | v_sql text; 263 | v_col name; 264 | v_operation varchar; 265 | v_newline char := E'\n'; 266 | begin 267 | if pghist.hist_exists(v_schema,v_table_name) then 268 | perform pghist.hist_objects_refresh(v_schema,v_table_name); 269 | return; 270 | end if; 271 | call pghist.hist_objects_name(v_schema, v_table_name, v_hist_data_table, v_hist_data_func_prefix, v_trigger_prefix, v_view_hist, v_func_changes, v_func_at_timestamp); 272 | call pghist.hist_table_columns(v_table_oid, v_columns_excluded, v_columns_name, v_columns_type, v_columns_comment); 273 | select array_agg(quote_ident(attname) order by col_pos) 274 | into v_columns_pkey 275 | from unnest( (select conkey from pg_constraint where conrelid=v_table_oid and contype='p') ) with ordinality c(col_num,col_pos) 276 | join pg_attribute a on attrelid=v_table_oid and attnum = col_num; 277 | if v_columns_pkey is null then 278 | raise exception 'PGSUITE-2002 Table does not have primary key'; 279 | end if; 280 | v_columns_immutable := pghist.hist_columns_immutable(v_columns_pkey, v_master_table_fkey); 281 | v_sql := 282 | 'create table '||v_hist_data_table||' ('||v_newline|| 283 | ' hist_statement_id bigint not null, -- references pghist.hist_statement(id) on delete cascade,'||v_newline|| 284 | ' hist_row_num int not null,'||v_newline|| 285 | ' hist_update_columns name[],'||v_newline; 286 | foreach v_col in array v_columns_immutable loop 287 | v_sql := v_sql||' '||v_col||' '||v_columns_type[array_position(v_columns_name,v_col)]||' not null,'||v_newline; 288 | end loop; 289 | foreach v_col in array v_columns_name loop 290 | if not v_col=any(v_columns_immutable) then 291 | v_sql := v_sql||' '||pghist.hist_ident('',v_col,'_old')||' '||v_columns_type[array_position(v_columns_name,v_col)]||','||v_newline; 292 | end if; 293 | end loop; 294 | v_sql := v_sql|| 295 | ' primary key ('||pghist.hist_columns_to_text(v_columns_pkey)||',hist_statement_id)'||v_newline|| 296 | ')'; 297 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 298 | call pghist.hist_execute_sql(v_schema, v_table_name, 'lock table '||v_hist_data_table||' in exclusive mode'); 299 | v_sql := 300 | 'insert into '||v_hist_data_table||' (hist_statement_id,hist_row_num,'||pghist.hist_columns_to_text(v_columns_immutable)||')'||v_newline|| 301 | ' select '||pghist.hist_statement_id('HIST_ENABLE')||',row_number() over (),'||pghist.hist_columns_to_text(v_columns_immutable)||' from only '||v_schema||'.'||v_table_name; 302 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 303 | if v_master_table_fkey is not null then 304 | call pghist.hist_execute_sql(v_schema, v_table_name, 'create index on '||v_hist_data_table||'('||pghist.hist_columns_to_text(v_master_table_fkey)||')'); 305 | end if; 306 | insert into pghist.hist_table(schema,name,pkey,master_table_schema,master_table_name,master_table_fkey,columns_excluded) 307 | values (v_schema,v_table_name,v_columns_pkey,v_master_table_schema,v_master_table_name,v_master_table_fkey,v_columns_excluded); 308 | perform pghist.hist_objects_refresh(v_schema, v_table_name); 309 | foreach v_operation in array array['insert','update','delete','truncate'] loop 310 | v_sql := 311 | 'create trigger '||pghist.hist_ident('',v_trigger_prefix,v_operation)|| 312 | ' '||case when v_operation='truncate' then 'before' else 'after' end||' '||v_operation|| 313 | ' on '||v_schema||'.'||v_table_name|| 314 | case when v_operation='truncate' then '' else ' referencing' end|| 315 | case when v_operation in ('insert','update') then ' new table as rows_new' else '' end|| 316 | case when v_operation in ('update','delete') then ' old table as rows_old' else '' end|| 317 | case when v_operation='truncate' then '' else ' for each statement' end|| 318 | ' execute procedure pghist.'||pghist.hist_ident('',v_hist_data_func_prefix,v_operation)||'();'; 319 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 320 | end loop; 321 | if v_master_table_schema is not null then 322 | perform pghist.hist_objects_refresh(v_master_table_schema, v_master_table_name); 323 | end if; 324 | end; $$; 325 | 326 | create or replace procedure pghist.hist_enable(table_name name) security definer language plpgsql as $$ 327 | declare 328 | v_schema name; 329 | v_table_name name; 330 | begin 331 | select quote_ident(n.nspname),quote_ident(c.relname) 332 | into v_schema,v_table_name 333 | from pg_class c 334 | join pg_namespace n on n.oid=c.relnamespace 335 | where c.oid=table_name::regclass::oid; 336 | call pghist.hist_enable(v_schema, v_table_name); 337 | end; $$; 338 | 339 | create or replace procedure pghist.hist_parent_refresh(schema name, table_name name) language plpgsql as $$ 340 | declare 341 | v_parent_schema name; 342 | v_parent_table_name name; 343 | begin 344 | select quote_ident(quote_ident(c.relnamespace::regnamespace::name)),quote_ident(c.relname) 345 | into v_parent_schema,v_parent_table_name 346 | from pg_inherits i 347 | join pg_class c on c.oid=i.inhparent 348 | where i.inhrelid=(select oid from pg_class where quote_ident(relnamespace::regnamespace::name)=schema and quote_ident(relname)=table_name); 349 | if v_parent_schema is not null then 350 | perform pghist.hist_objects_refresh(v_parent_schema,v_parent_table_name); 351 | end if; 352 | end; $$; 353 | 354 | create or replace procedure pghist.hist_disable(schema name, table_name name) security definer language plpgsql as $$ 355 | declare 356 | v_schema name := pghist.hist_ident(schema); 357 | v_table_name name := pghist.hist_ident(table_name); 358 | v_table_oid oid := to_regclass(v_schema||'.'||v_table_name)::oid; 359 | v_master_table_schema name; 360 | v_master_table_name name; 361 | v_hist_data_table name; 362 | v_hist_data_func_prefix name; 363 | v_trigger_prefix name; 364 | v_view_hist name; 365 | v_func_changes name; 366 | v_func_at_timestamp name; 367 | v_operation varchar; 368 | begin 369 | select v_master_table_schema,master_table_name 370 | into v_master_table_schema,v_master_table_name 371 | from pghist.hist_table ht 372 | where ht.schema=v_schema and ht.name=v_table_name; 373 | call pghist.hist_objects_name(v_schema, v_table_name, v_hist_data_table, v_hist_data_func_prefix, v_trigger_prefix, v_view_hist, v_func_changes, v_func_at_timestamp); 374 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop view if exists '||v_schema||'.'||v_view_hist); 375 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop function if exists '||v_schema||'.'||v_func_changes); 376 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop function if exists '||v_schema||'.'||v_func_at_timestamp); 377 | foreach v_operation in array array['insert','update','delete','truncate'] loop 378 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop function if exists pghist.'||pghist.hist_ident('',v_hist_data_func_prefix,v_operation)||' cascade'); 379 | end loop; 380 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop table if exists '||v_hist_data_table||' cascade'); 381 | delete from pghist.hist_table where hist_table.schema=v_schema and hist_table.name=v_table_name; 382 | call pghist.hist_parent_refresh(v_schema, v_table_name); 383 | if v_master_table_schema is not null then 384 | perform pghist.hist_objects_refresh(v_master_table_schema, v_master_table_name); 385 | end if; 386 | end; $$; 387 | 388 | create or replace procedure pghist.hist_disable(table_name name) security definer language plpgsql as $$ 389 | declare 390 | v_schema name; 391 | v_table_name name; 392 | begin 393 | select quote_ident(n.nspname),quote_ident(c.relname) 394 | into v_schema,v_table_name 395 | from pg_class c 396 | join pg_namespace n on n.oid=c.relnamespace 397 | where c.oid=table_name::regclass::oid; 398 | call pghist.hist_disable(v_schema, v_table_name); 399 | end; $$; 400 | 401 | create or replace function pghist.hist_event_column_rename(schema name, table_name name, table_oid oid, column_name_old name, column_num int) returns void security definer language plpgsql as $$ 402 | declare 403 | v_schema name := pghist.hist_ident(schema); 404 | v_table_name name := pghist.hist_ident(table_name); 405 | v_column_name_old name := quote_ident(column_name_old); 406 | v_column_name_new name := quote_ident((select attname from pg_attribute where attrelid=table_oid and attnum=column_num)); 407 | v_hist_column_name_old name := pghist.hist_ident('',v_column_name_old,'_old'); 408 | -- 409 | v_hist_data_table name; 410 | v_hist_data_func_prefix name; 411 | v_trigger_prefix name; 412 | v_view_hist name; 413 | v_func_changes name; 414 | v_func_at_timestamp name; 415 | begin 416 | if v_column_name_old is null or v_column_name_new is null or v_column_name_old=v_column_name_new then 417 | return; 418 | end if; 419 | call pghist.hist_objects_name(v_schema, v_table_name, v_hist_data_table, v_hist_data_func_prefix, v_trigger_prefix, v_view_hist, v_func_changes, v_func_at_timestamp); 420 | if not exists (select from pg_attribute where attrelid=v_hist_data_table::regclass::oid and quote_ident(attname)=v_hist_column_name_old) then 421 | return; 422 | end if; 423 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop view if exists '||v_schema||'.'||v_view_hist); 424 | call pghist.hist_execute_sql(v_schema, v_table_name, 'alter table '||v_hist_data_table||' rename column '||v_hist_column_name_old||' to '||pghist.hist_ident('',v_column_name_new,'_old')); 425 | call pghist.hist_execute_sql(v_schema, v_table_name, 'update '||v_hist_data_table||' set hist_update_columns=array_replace(hist_update_columns,'||quote_literal(v_column_name_old)||','||quote_literal(v_column_name_new)||') where '||quote_literal(v_column_name_old)||'=any(hist_update_columns)'); 426 | end; 427 | $$; 428 | 429 | create or replace function pghist.hist_event_ddl_command() returns event_trigger stable security definer language plpgsql as $$ 430 | declare 431 | v_table record; 432 | begin 433 | for v_table in 434 | select t.schema,t.name 435 | from pg_event_trigger_ddl_commands() e 436 | join pg_class c on c.oid=e.objid 437 | join pghist.hist_table t on t.schema=quote_ident(e.schema_name) and t.name=quote_ident(c.relname) 438 | where e.object_type='table' 439 | loop 440 | perform pghist.hist_objects_refresh(v_table.schema, v_table.name); 441 | end loop; 442 | for v_table in 443 | select t.schema,t.name,e.objid oid,a.attname column_name_old,e.objsubid column_num 444 | from pg_event_trigger_ddl_commands() e 445 | join pg_class c on c.oid=e.objid 446 | join pg_attribute a on a.attrelid=e.objid and a.attnum=e.objsubid 447 | join pghist.hist_table t on t.schema=quote_ident(e.schema_name) and t.name=quote_ident(c.relname) 448 | where e.object_type='table column' 449 | loop 450 | perform pghist.hist_event_column_rename(v_table.schema, v_table.name, v_table.oid, v_table.column_name_old, v_table.column_num); 451 | perform pghist.hist_objects_refresh(v_table.schema, v_table.name); 452 | end loop; 453 | for v_table in 454 | select t.schema,t.name 455 | from pg_event_trigger_ddl_commands() e 456 | join pg_index i on i.indexrelid=e.objid 457 | join pg_class c on c.oid=i.indrelid 458 | join pghist.hist_table t on t.schema=quote_ident(e.schema_name) and t.name=quote_ident(c.relname) 459 | where e.object_type='index' 460 | loop 461 | perform pghist.hist_objects_refresh(v_table.schema, v_table.name); 462 | end loop; 463 | end; 464 | $$; 465 | 466 | create or replace function pghist.hist_event_drop_table() returns event_trigger security definer language plpgsql as $$ 467 | declare 468 | v_table record; 469 | begin 470 | for v_table in 471 | select t.schema,t.name 472 | from pg_event_trigger_dropped_objects() o 473 | join pghist.hist_table t on o.object_type='table' and t.schema=quote_ident(o.schema_name) and t.name=quote_ident(o.object_name) 474 | loop 475 | call pghist.hist_disable(v_table.schema, v_table.name); 476 | end loop; 477 | end; 478 | $$; 479 | 480 | do $$ begin 481 | if not exists (select 1 from pg_event_trigger where evtname='pghist_event_tg_ddl_command') then 482 | create event trigger pghist_event_tg_ddl_command on ddl_command_end when tag in ('ALTER TABLE','CREATE INDEX','COMMENT') execute procedure pghist.hist_event_ddl_command(); 483 | end if; 484 | if not exists (select 1 from pg_event_trigger where evtname='pghist_event_tg_drop_table') then 485 | create event trigger pghist_event_tg_drop_table on sql_drop when tag in ('DROP TABLE','DROP SCHEMA') execute function pghist.hist_event_drop_table(); 486 | end if; 487 | end $$; 488 | 489 | 490 | create or replace function pghist.hist_objects_refresh(schema name, table_name name) returns void security definer language plpgsql as $body$ 491 | declare 492 | v_schema name := pghist.hist_ident(schema); 493 | v_table_name name := pghist.hist_ident(table_name); 494 | v_table_oid oid := (v_schema||'.'||v_table_name)::regclass::oid; 495 | v_table_comment varchar := coalesce(quote_literal(col_description(v_table_oid, 0)),'null'); 496 | v_table_owner name := (select relowner::regrole::name from pg_class where oid=v_table_oid); 497 | v_tables_inherited name[][]; 498 | v_columns_name name[]; 499 | v_columns_type name[]; 500 | v_columns_pkey name[]; 501 | v_columns_comment varchar[]; 502 | v_columns_immutable name[]; 503 | v_columns_excluded name[]; 504 | v_columns_value name[]; 505 | v_columns_value_old name[]; 506 | v_columns_expr_value_new_desc varchar[]; 507 | v_columns_expr_value_old_desc varchar[]; 508 | v_row_desc_expr varchar; 509 | -- 510 | v_hist_data_table name; 511 | v_hist_data_func_prefix name; 512 | v_trigger_prefix name; 513 | v_view_hist name; 514 | v_func_changes name; 515 | v_func_at_timestamp name; 516 | -- 517 | v_sql text; 518 | v_sql_part text; 519 | v_sql_condition text; 520 | v_sql_hist_to_row text; 521 | v_sql_hist_data_func name; 522 | v_col name; 523 | v_operation varchar; 524 | v_expression varchar; 525 | v_type_convert varchar; 526 | v_temp_table_at_timestamp name; 527 | v_i int; 528 | v_rec record; 529 | v_newline char := E'\n'; 530 | begin 531 | call pghist.hist_objects_name(v_schema, v_table_name, v_hist_data_table, v_hist_data_func_prefix, v_trigger_prefix, v_view_hist, v_func_changes, v_func_at_timestamp); 532 | select ht.pkey,pghist.hist_columns_immutable(ht.pkey,ht.master_table_fkey),ht.columns_excluded 533 | into v_columns_pkey,v_columns_immutable,v_columns_excluded 534 | from pghist.hist_table ht 535 | where ht.schema=v_schema and ht.name=v_table_name; 536 | call pghist.hist_table_columns(v_table_oid, v_columns_excluded, v_columns_name, v_columns_type, v_columns_comment); 537 | select array_agg(array[child_schema,child_table_name] order by child_schema,child_table_name) 538 | into v_tables_inherited 539 | from ( 540 | select quote_ident(n.nspname) child_schema, quote_ident(c.relname) child_table_name 541 | from pg_inherits i 542 | join pg_class c on c.oid=i.inhrelid 543 | join pg_namespace n on n.oid=c.relnamespace 544 | where i.inhparent = v_table_oid 545 | ) c 546 | join pghist.hist_table t on t.schema=child_schema and t.name=child_table_name; 547 | -- 548 | for v_rec in 549 | select quote_ident(substring(attname,1,length(attname)-4)) column_name, quote_ident(attname) column_name_old 550 | from pg_attribute 551 | where attrelid=v_hist_data_table::regclass::oid and not quote_ident(attname)=any(v_columns_immutable) and attnum>3 and not attisdropped 552 | and (quote_ident(attname),atttypid) not in ( 553 | select pghist.hist_ident('',quote_ident(attname),'_old'),atttypid from pg_attribute where attrelid=v_table_oid and attnum>0 and not attisdropped and not quote_ident(attname)=any(v_columns_excluded) 554 | ) 555 | loop 556 | call pghist.hist_execute_sql(v_schema, v_table_name, 'drop view if exists '||v_schema||'.'||v_view_hist); 557 | call pghist.hist_execute_sql(v_schema, v_table_name, 'alter table '||v_hist_data_table||' drop column '||v_rec.column_name_old); 558 | call pghist.hist_execute_sql(v_schema, v_table_name, 'update '||v_hist_data_table||' set hist_update_columns=array_remove(hist_update_columns,'||quote_literal(v_rec.column_name)||') where '||quote_literal(v_rec.column_name)||'=any(hist_update_columns)'); 559 | end loop; 560 | for v_rec in 561 | select quote_ident(attname) column_name, typname column_type, pg_get_expr(d.adbin,d.adrelid) default_value 562 | from pg_attribute a 563 | join pg_type t on t.oid=a.atttypid 564 | left join pg_attrdef d on d.adrelid=a.attrelid and d.adnum=a.attnum 565 | where attrelid=v_table_oid and not quote_ident(attname)=any(v_columns_immutable) and attnum>0 and not attisdropped and not quote_ident(attname)=any(v_columns_excluded) 566 | and pghist.hist_ident('',quote_ident(attname),'_old') not in (select quote_ident(attname) from pg_attribute where attrelid=v_hist_data_table::regclass::oid and attnum>0 and not attisdropped) 567 | order by attnum 568 | loop 569 | call pghist.hist_execute_sql(v_schema, v_table_name, 'alter table '||v_hist_data_table||' add column '||pghist.hist_ident('',v_rec.column_name,'_old')||' '||v_rec.column_type); 570 | if v_rec.default_value is not null then 571 | call pghist.hist_execute_sql(v_schema, v_table_name, 'lock table '||v_hist_data_table||' in exclusive mode'); 572 | v_sql := 573 | 'insert into '||v_hist_data_table||' (hist_statement_id,hist_row_num,hist_update_columns,'||pghist.hist_columns_to_text(v_columns_immutable)||')'||v_newline|| 574 | ' select '||pghist.hist_statement_id('UPDATE')||',row_number() over (),array['||pg_catalog.quote_literal(v_rec.column_name)||'],'||pghist.hist_columns_to_text(v_columns_immutable)||' from only '||v_schema||'.'||v_table_name; 575 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 576 | end if; 577 | end loop; 578 | select array_agg(col),array_agg(pghist.hist_ident('',col,'_old')) into v_columns_value,v_columns_value_old from unnest(v_columns_name) col where not col = any(v_columns_immutable); 579 | for v_i in 1..array_length(v_columns_name,1) loop 580 | v_expression := pghist.hist_expression_value_desc_current(v_schema, v_table_name, v_columns_name[v_i]); 581 | if v_expression is not null then 582 | v_sql_part := ' execute '||quote_literal('select ('||v_expression||')')||' into v_change.value_'; 583 | v_columns_expr_value_new_desc[v_i] := v_sql_part||'new_desc using v_row.'||v_columns_name[v_i]||';'; 584 | v_columns_expr_value_old_desc[v_i] := v_sql_part||'old_desc using v_row.'||v_columns_name[v_i]||';'; 585 | else 586 | v_columns_expr_value_new_desc[v_i] := ' v_change.value_new_desc := v_change.value_new;'; 587 | v_columns_expr_value_old_desc[v_i] := ' v_change.value_old_desc := v_change.value_old;'; 588 | end if; 589 | end loop; 590 | v_row_desc_expr := 'execute '||quote_literal('select ('||pghist.hist_expression_row_desc_current(v_schema, v_table_name)||')')||' into v_change.row_desc using v_row;'; 591 | -- 592 | v_sql_hist_data_func := 'pghist.'||pghist.hist_ident('',v_hist_data_func_prefix,'insert'); 593 | v_sql := 594 | 'create or replace function '||v_sql_hist_data_func||'() returns trigger language plpgsql security definer as $$'||v_newline|| 595 | 'declare '||v_newline|| 596 | ' v_statement_id bigint = pghist.hist_statement_id(tg_op);'||v_newline|| 597 | 'begin '||v_newline|| 598 | ' insert into '||v_hist_data_table||'(hist_statement_id,hist_row_num,'||pghist.hist_columns_to_text(v_columns_immutable)||')'||v_newline|| 599 | ' select v_statement_id,row_number() over (),'||pghist.hist_columns_to_text(v_columns_immutable)||v_newline|| 600 | ' from rows_new;'||v_newline|| 601 | ' return null;'||v_newline|| 602 | 'end;'||v_newline|| 603 | '$$'; 604 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 605 | call pghist.hist_execute_sql(v_schema, v_table_name, 'grant execute on function '||v_sql_hist_data_func||' to '||v_table_owner); 606 | v_sql_hist_data_func := 'pghist.'||pghist.hist_ident('',v_hist_data_func_prefix,'update'); 607 | v_sql := 608 | 'create or replace function '||v_sql_hist_data_func||'() returns trigger language plpgsql security definer as $$'||v_newline|| 609 | 'declare '||v_newline|| 610 | ' v_statement_id bigint = pghist.hist_statement_id(tg_op);'||v_newline|| 611 | 'begin '||v_newline|| 612 | ' if exists ('||v_newline|| 613 | ' select from rows_old o'||v_newline|| 614 | ' left join rows_new n on '||pghist.hist_columns_to_text(v_columns_immutable,$$ 'o.'||col||'=n.'||col $$,' and ')||v_newline|| 615 | ' where n.'||v_columns_pkey[1]||' is null'||v_newline|| 616 | ' ) then '||v_newline|| 617 | ' raise exception ''PGSUITE-2001 Update column(s) '||pghist.hist_columns_to_text(v_columns_immutable,$$ pghist.hist_ident_in_str(col) $$)||' of table '||pghist.hist_ident_in_str(v_schema)||'.'||pghist.hist_ident_in_str(v_table_name)||' is not allowed'';'||v_newline|| 618 | ' end if;'||v_newline|| 619 | ' insert into '||v_hist_data_table||'(hist_statement_id,hist_row_num,hist_update_columns,'||pghist.hist_columns_to_text(v_columns_immutable)||pghist.hist_columns_to_text(v_columns_value_old,$$ ','||col $$,'')||')'||v_newline|| 620 | ' select v_statement_id,'||v_newline|| 621 | ' hist_row_num,'||v_newline|| 622 | ' array[]::name[]'||v_newline; 623 | v_sql_part := pghist.hist_columns_to_text(v_columns_immutable,$$ ' o.'||col||',' $$,v_newline)||v_newline; 624 | for v_i in 1..array_length(v_columns_value,1) loop 625 | v_col := v_columns_value[v_i]; 626 | v_type_convert := case when v_columns_type[array_position(v_columns_name, v_col)] in ('json','_json','xml','_xml') then '::text' else '' end; 627 | v_sql_condition := '(o.'||v_col||v_type_convert||'!=n.'||v_col||v_type_convert||') or (o.'||v_col||' is null and n.'||v_col||' is not null) or (o.'||v_col||' is not null and n.'||v_col||' is null)'; 628 | v_sql := v_sql||' ||(case when '||v_sql_condition||' then '||quote_literal(v_col)||'::name end)'||case when v_i=array_length(v_columns_value,1) then ',' else '' end||v_newline; 629 | v_sql_part := v_sql_part||' case when '||v_sql_condition||' then o.'||v_col||' end'||case when v_i=transaction_timestamp'||v_newline|| 838 | ' union all'||v_newline|| 839 | ' select null,null,null,'||pghist.hist_columns_to_text(v_columns_immutable)||pghist.hist_columns_to_text(v_columns_value,$$ ','||col $$,'')||v_newline|| 840 | ' from only '||v_schema||'.'||v_table_name||v_newline|| 841 | ' order by '||pghist.hist_columns_to_text(v_columns_pkey)||',hist_statement_id desc;'||v_newline|| 842 | ' v_column name;'||v_newline|| 843 | 'begin'||v_newline|| 844 | ' drop table if exists '||v_temp_table_at_timestamp||';'||v_newline|| 845 | ' create temp table '||v_temp_table_at_timestamp||' as select * from '||v_schema||'.'||v_table_name||' limit 0;'||v_newline|| 846 | ' open v_cur_hist;'||v_newline|| 847 | ' loop'||v_newline|| 848 | ' fetch v_cur_hist into v_hist;'||v_newline|| 849 | ' v_hist_not_found := not found;'||v_newline|| 850 | ' if (v_hist_not_found and v_row.'||v_columns_pkey[1]||' is not null) or ('||pghist.hist_columns_to_text(v_columns_pkey,$$ 'v_row.'||col||'!=v_hist.'||col $$,' or ')||') then'||v_newline|| 851 | ' insert into '||v_temp_table_at_timestamp||' values (v_row.*);'||v_newline|| 852 | ' v_row := null;'||v_newline|| 853 | ' end if;'||v_newline|| 854 | ' exit when v_hist_not_found;'||v_newline|| 855 | ' if v_hist.hist_operation is null or v_hist.hist_operation in (''DELETE'',''TRUNCATE'') then'||v_newline|| 856 | ' '||v_sql_hist_to_row||v_newline|| 857 | ' continue;'||v_newline|| 858 | ' end if;'||v_newline|| 859 | ' if v_hist.hist_operation = ''UPDATE'' then'||v_newline|| 860 | ' foreach v_column in array v_hist.hist_update_columns loop'||v_newline; 861 | foreach v_col in array v_columns_value loop 862 | v_sql := v_sql|| 863 | ' if v_column='||quote_literal(v_col)||' then v_row.'||v_col||':=v_hist.'||pghist.hist_ident('',v_col,'_old')||'; continue; end if;'||v_newline; 864 | end loop; 865 | v_sql := v_sql|| 866 | ' end loop;'||v_newline|| 867 | ' continue;'||v_newline|| 868 | ' end if;'||v_newline|| 869 | ' if v_hist.hist_operation in (''INSERT'',''HIST_ENABLE'') then'||v_newline|| 870 | ' v_row := null;'||v_newline|| 871 | ' continue;'||v_newline|| 872 | ' end if;'||v_newline|| 873 | ' end loop;'||v_newline|| 874 | ' close v_cur_hist;'||v_newline; 875 | if v_tables_inherited is not null then 876 | v_sql := v_sql||' if tables_inherited then'||v_newline; 877 | for v_i in 1..array_length(v_tables_inherited, 1) loop 878 | v_sql := v_sql|| 879 | ' insert into '||v_temp_table_at_timestamp||v_newline|| 880 | ' select '||pghist.hist_columns_to_text(v_columns_name)||v_newline|| 881 | ' from '||v_tables_inherited[v_i][1]||'.'||pghist.hist_ident('',v_tables_inherited[v_i][2],'_at_timestamp')||'(transaction_timestamp, tables_inherited);'||v_newline; 882 | end loop; 883 | v_sql := v_sql||' end if;'||v_newline; 884 | end if; 885 | select 886 | string_agg( 887 | ' create index on '||v_temp_table_at_timestamp||' ('|| 888 | (select string_agg(quote_ident(attname), ',' order by col_pos) 889 | from unnest(indkey) with ordinality col(col_num,col_pos) 890 | join pg_attribute on attrelid=indrelid and attnum=col_num 891 | )|| 892 | '); -- '||relname||v_newline 893 | , '' order by relname) 894 | into v_sql_part 895 | from pg_index 896 | join pg_class on pg_class.oid=indexrelid 897 | where indrelid=v_table_oid and 0!=any(indkey); 898 | v_sql := v_sql||v_sql_part|| 899 | ' for v_row in (select * from '||v_temp_table_at_timestamp||') loop'||v_newline|| 900 | ' return next v_row;'||v_newline|| 901 | ' end loop;'||v_newline|| 902 | 'end;'||v_newline|| 903 | '$func$'; 904 | call pghist.hist_execute_sql(v_schema, v_table_name, v_sql); 905 | call pghist.hist_execute_sql(v_schema, v_table_name, 'grant execute on function '||v_schema||'.'||v_func_at_timestamp||' to '||v_table_owner||' with grant option'); 906 | -- 907 | call pghist.hist_parent_refresh(v_schema, v_table_name); 908 | end; $body$; 909 | 910 | 911 | create or replace procedure pghist.hist_expression_row_desc(schema name, table_name name, expression varchar) language plpgsql as $$ 912 | declare 913 | v_schema name := pghist.hist_ident(schema); 914 | v_table_name name := pghist.hist_ident(table_name); 915 | begin 916 | update pghist.hist_table ht set expression_row_desc=expression where ht.schema=v_schema and ht.name=v_table_name; 917 | call pghist.hist_enable(schema, table_name); 918 | end; $$; 919 | 920 | create or replace function pghist.hist_expression_row_desc_default(schema name, table_name name) returns varchar language plpgsql as $$ 921 | declare 922 | v_table_oid oid := (pghist.hist_ident(schema)||'.'||pghist.hist_ident(table_name))::regclass::oid; 923 | begin 924 | return ( 925 | select quote_literal(coalesce(col_description(v_table_oid, 0), table_name)||' #')||'||'||string_agg('$1.'||quote_ident(attname), '||'',''||' order by col_pos) expr 926 | from unnest( (select conkey from pg_constraint where conrelid=v_table_oid and contype='p') ) with ordinality c(col_num,col_pos) 927 | join pg_attribute a on attrelid=v_table_oid and attnum = col_num 928 | ); 929 | end; $$; 930 | 931 | create or replace function pghist.hist_expression_row_desc_current(schema name, table_name name) returns varchar language plpgsql as $$ 932 | declare 933 | v_schema name := pghist.hist_ident(schema); 934 | v_table_name name := pghist.hist_ident(table_name); 935 | begin 936 | return (select coalesce(expression_row_desc,pghist.hist_expression_row_desc_default(ht.schema,ht.name)) from pghist.hist_table ht where ht.schema=v_schema and ht.name=v_table_name); 937 | end; $$; 938 | 939 | create or replace procedure pghist.hist_expression_value_desc(schema name, table_name name, column_name name, expression varchar) language plpgsql as $$ 940 | declare 941 | v_schema name := pghist.hist_ident(schema); 942 | v_table_name name := pghist.hist_ident(table_name); 943 | v_column_name name := pghist.hist_ident(column_name); 944 | begin 945 | insert into pghist.hist_table_column(schema,table_name,column_name,expression_value_desc) 946 | values (v_schema,v_table_name,v_column_name,expression) 947 | on conflict on constraint hist_table_column_pkey do 948 | update set expression_value_desc = expression; 949 | call pghist.hist_enable(v_schema, v_table_name); 950 | end; $$; 951 | 952 | create or replace function pghist.hist_expression_value_desc_default(schema name, table_name name, column_name name) returns varchar language plpgsql as $$ 953 | declare 954 | v_table_oid oid := (pghist.hist_ident(schema)||'.'||pghist.hist_ident(table_name))::regclass::oid; 955 | v_column_name name := pghist.hist_ident(column_name); 956 | begin 957 | return ( 958 | select 'select '||quote_ident(f_text.attname)||' from '||quote_ident(f_nsp.nspname)||'.'||quote_ident(f_tab.relname)||' where '||quote_ident(f_key.attname)||'=$1' 959 | from pg_constraint c 960 | join pg_attribute ca on ca.attrelid=c.conrelid and ca.attnum=c.conkey[1] and quote_ident(ca.attname)=v_column_name 961 | join pg_class f_tab on f_tab.oid=c.confrelid 962 | join pg_namespace f_nsp on f_nsp.oid=f_tab.relnamespace 963 | join pg_attribute f_key on f_key.attrelid=c.confrelid and f_key.attnum=c.confkey[1] 964 | join pg_attribute f_text on f_text.attrelid=c.confrelid and f_text.attnum!=f_key.attnum 965 | join pg_type t on t.oid=f_text.atttypid and t.typcategory='S' 966 | where c.conrelid=v_table_oid and c.contype='f' and array_length(c.conkey,1)=1 967 | order by f_text.attnum 968 | limit 1 969 | ); 970 | end; $$; 971 | 972 | create or replace function pghist.hist_expression_value_desc_current(schema name, table_name name, column_name name) returns varchar language plpgsql as $$ 973 | declare 974 | v_schema name := pghist.hist_ident(schema); 975 | v_table_name name := pghist.hist_ident(table_name); 976 | v_column_name name := pghist.hist_ident(column_name); 977 | begin 978 | return coalesce( 979 | (select expression_value_desc from pghist.hist_table_column htc where htc.schema=v_schema and htc.table_name=v_table_name and htc.column_name=v_column_name), 980 | pghist.hist_expression_value_desc_default(v_schema, v_table_name, v_column_name) 981 | ); 982 | end; $$; 983 | 984 | create or replace function pghist.hist_default_operation_name(operation varchar) returns varchar language plpgsql as $$ 985 | begin 986 | return case 987 | when operation = 'HIST_ENABLE' then 'History start' 988 | when operation = 'INSERT' then 'Creation' 989 | when operation = 'UPDATE' then 'Modification' 990 | when operation = 'DELETE' then 'Deletion' 991 | when operation = 'TRUNCATE' then 'Cleaning' 992 | end; 993 | end; $$; 994 | 995 | create or replace function pghist.hist_default_db_user_name(db_user name) returns varchar language plpgsql as $$ begin return db_user; end; $$; 996 | create or replace function pghist.hist_default_app_user() returns varchar language plpgsql as $$ begin return current_setting('app.user', true); end; $$; 997 | create or replace function pghist.hist_default_app_user_name(app_user name) returns varchar language plpgsql as $$ begin return app_user; end; $$; 998 | create or replace function pghist.hist_default_app_client_addr() returns inet language plpgsql as $$ begin return current_setting('app.client_addr', true)::inet; end; $$; 999 | create or replace function pghist.hist_default_app_client_hostname() returns varchar language plpgsql as $$ begin return current_setting('app.client_hostname', true); end; $$; 1000 | 1001 | create table if not exists pghist.hist_column_custom_function( 1002 | column_name name primary key check (column_name in ('operation_name','db_user_name','app_user','app_user_name','app_client_addr','app_client_hostname')), 1003 | custom_function name not null 1004 | ); 1005 | 1006 | create or replace function pghist.hist_column_custom_function_current(column_name name) returns varchar language plpgsql as $$ 1007 | declare 1008 | v_column_name name := column_name; 1009 | begin 1010 | return coalesce((select custom_function from pghist.hist_column_custom_function f where f.column_name=v_column_name), 'pghist.hist_default_'||v_column_name); 1011 | end; $$; 1012 | 1013 | create or replace procedure pghist.hist_column_custom_function(column_name name, custom_function name) language plpgsql as $$ 1014 | declare 1015 | v_custom_function name := custom_function; 1016 | v_rec_table record; 1017 | begin 1018 | insert into pghist.hist_column_custom_function 1019 | values (column_name, v_custom_function) 1020 | on conflict on constraint hist_column_custom_function_pkey do 1021 | update set custom_function = v_custom_function; 1022 | if column_name in ('app_user','app_client_addr','app_client_hostname') then 1023 | call pghist.hist_create_function_transaction_id(); 1024 | else 1025 | for v_rec_table in 1026 | select schema,name from pghist.hist_table 1027 | loop 1028 | call pghist.hist_enable(v_rec_table.schema, v_rec_table.name); 1029 | end loop; 1030 | end if; 1031 | end; $$; 1032 | 1033 | create or replace procedure pghist.hist_create_function_transaction_id() security definer language plpgsql as $body$ 1034 | begin 1035 | execute $$ 1036 | 1037 | create or replace function pghist.hist_transaction_id() returns bigint language plpgsql as $func$ 1038 | declare 1039 | v_id_text varchar; 1040 | v_id bigint; 1041 | begin 1042 | v_id_text := current_setting('pghist.transaction_id', true); 1043 | if v_id_text!='' then 1044 | return v_id_text::bigint; 1045 | end if; 1046 | v_id := reverse(nextval('pghist.hist_transaction_seq')::varchar); 1047 | insert into pghist.hist_transaction(id, xid, timestamp_start, application_name, backend_pid, backend_start, db_user, db_client_addr, db_client_hostname, app_user, app_client_addr, app_client_hostname) 1048 | select v_id, txid_current(), xact_start, application_name, pg_backend_pid(), backend_start, usename, client_addr, client_hostname, $$ 1049 | || pghist.hist_column_custom_function_current('app_user') || '(), ' || pghist.hist_column_custom_function_current('app_client_addr') || '(), ' || pghist.hist_column_custom_function_current('app_client_hostname') || '()' || $$ 1050 | from pg_stat_activity p where pid = pg_backend_pid(); 1051 | perform set_config('pghist.transaction_id', v_id::varchar, true); 1052 | return v_id; 1053 | end; $func$; 1054 | 1055 | $$; 1056 | end; $body$; 1057 | 1058 | call pghist.hist_create_function_transaction_id(); 1059 | 1060 | 1061 | -------------------------------------------------------------------------------- /readme.md: -------------------------------------------------------------------------------- 1 | ## PGHist | History and audit of table changes in PostgreSQL 2 | 3 | Tool `PGHist` keeps history of table changes and allows to get log(audit) of changes by row, 4 | list of changes by field indicating user, time of the change, SQL query, transaction, other technical information 5 | and table as of date-time in the past (versioning). 6 | To display information in user interface, SQL expressions are defined to describe changed table rows and fields. 7 | It is possible to override the operation name and username functions. 8 | 9 | ### Design and working principle ### 10 | 11 | PGHIST is a schema with procedures and common tables: transactions, SQL expressions etc. 12 | When history is enabled (procedure `pghist.hist_enable`), for specified table created additional table, triggers for insert,update,delete,truncate, stored procedures and view for obtaining data. 13 | When a table is changed, triggers are fired that modify the history table. 14 | There are also event triggers that rebuild the history table and recreate the stored procedures. 15 | 16 | ### Installation ### 17 | 18 | The installer is [pghist_init.sql](https://github.com/PGHist/PGHist/raw/main/pghist_init.sql) file that creates `pghist` schema. 19 | The installation consists in executing it in the psql terminal client or SQL manager, for example: 20 | 21 | ```bash 22 | wget -O - -q https://github.com/PGHist/PGHist/raw/main/pghist_init.sql | psql -d [database] 23 | ``` 24 | 25 | Optional. If the developers are not superusers, need to grant them privileges on the pghist schema and its procedures. 26 | To do this, use the SQL script [pghist_grants.sql](https://github.com/PGHist/PGHist/raw/main/pghist_grants.sql) with the roles variable. For example: 27 | 28 | ```bash 29 | wget -O - -q https://github.com/PGHist/PGHist/raw/main/pghist_grants.sql | psql -d [database] -v roles=[developers] 30 | ``` 31 | 32 | ### Extension ### 33 | 34 | To install `PGHist` as an extension, unpack the [pghist_extension.tar](https://github.com/PGHist/PGHist/raw/main/extension/pghist_extension.tar) archive into the [sharedir]/extension directory of the postgres installation, for example (run as root): 35 | 36 | ```bash 37 | wget -O - -q https://github.com/PGHist/PGHist/raw/main/extension/pghist_extension.tar | tar x -C `su - postgres -c "pg_config --sharedir"`/extension 38 | ``` 39 | More info on page [download](https://pghist.org/en/download/) 40 | 41 | ### Simple example ### 42 | 43 | ```sql 44 | -- Create table 45 | create table example( 46 | id int primary key, 47 | name varchar(20), 48 | number numeric(10,2), 49 | date date 50 | ); 51 | 52 | -- Enable keeping history 53 | call pghist.hist_enable('example'); 54 | 55 | -- Change table 56 | insert into example values (1, 'Example', 10, current_date); 57 | update example set number=20, date=date-1; 58 | 59 | -- View change log by row 60 | select * from example_hist; 61 | 62 | -- View changes by field 63 | select * from example_changes(); 64 | 65 | -- View table at timestamp 66 | select * from example_at_timestamp(now()-interval '10 second'); 67 | ``` 68 | 69 | All examples in directory [example](https://github.com/PGHist/PGHist/tree/main/example) 70 | 71 | ### Main functions and view ### 72 | 73 | * **pghist.hist\_enable(\[schema\],\[table\])** - enable history keeping 74 | 75 | * **\[schema\].\[table\]_hist** - log(audit) of changes by row, optimized for analysis 76 | 77 | * **\[schema\].\[table\]\_changes** - list of changes by field, optimized for display to the user 78 | 79 | * **\[schema\].\[table\]\_at\_timestamp** - table at date-time in the past (versioning) 80 | 81 | Documentation in file [documentation/documentation.html](https://htmlpreview.github.io/?https://github.com/PGSuite/PGHist/blob/main/documentation/documentation.html) 82 | 83 | ### Important qualities ### 84 | 85 | * **Storage optimization** - saving only old values of changed fields and primary key. The Transaction-Expression-Row storage structure matches the operation of the DBMS and minimizes redundancy. 86 | * **Versatility** - possible to get change log, list of only changed data from several tables and table at a point in time. 87 | * **Descriptions** - for each table and its columns, it is possible to define SQL expressions to describe changed rows and field values. By default, descriptions are created for foreign key fields and table rows 88 | * **Inheritance** - stored procedures have parameter "cascade" that allows you to get data with or without inheritance 89 | * **Transaction and SQL statements** - changes have a reference to SQL statements, that references a transaction. Can get all the changes made within a single transaction or rows within one expression 90 | * **Indexes** - for a history table, an index is built on the primary key column(s), for a table at a point in time - standard indexes on columns 91 | * **Condition (optional)** - when getting a list of changes, you specify a condition on the primary key or foreign key referencing the master table 92 | * **Autocorrection** - when performing DDL operations on a table (alter table, create index, etc.), a trigger fires, that corrects the history keeping. When a table is deleted, its history is also deleted 93 | 94 | Overview on site [pghist.org](https://pghist.org/en/) 95 | 96 | ### Support ### 97 | 98 | Of course you can create an issue, I will answer all requests. 99 | Also I will help to install and use the tool. 100 | Welcome to discussion ! 101 | 102 | WhatsApp: [PGSuite (+7-936-1397626)](https://wa.me/79361397626) 103 | email: [support\@pgsuite.org](mailto:support@pgsuite.org?subject=PGXLS) 104 | 105 | --------------------------------------------------------------------------------