edit table add missing log overflow and update log partition function
This commit is contained in:
@@ -13,54 +13,69 @@ DECLARE
|
||||
end_date DATE;
|
||||
timeformat TEXT := 'YYYY';
|
||||
selector TEXT := 'year';
|
||||
base_table TEXT := 'edit_log_';
|
||||
_interval INTERVAL;
|
||||
_interval_next INTERVAL;
|
||||
base_table TEXT := 'edit_log';
|
||||
_interval INTERVAL := '1 ' || selector;
|
||||
_interval_next INTERVAL := '2 ' || selector;
|
||||
table_name TEXT;
|
||||
-- compare date column
|
||||
compare_date DATE := NEW.event_date;
|
||||
compare_date_name TEXT := 'event_date';
|
||||
-- the create commands
|
||||
command_create_table TEXT := 'CREATE TABLE IF NOT EXISTS {TABLE_NAME} (CHECK({COMPARE_DATE_NAME} >= {START_DATE} AND {COMPARE_DATE_NAME} < {END_DATE})) INHERITS ({BASE_NAME})';
|
||||
command_create_primary_key TEXT := 'ALTER TABLE {TABLE_NAME} ADD PRIMARY KEY ({BASE_TABLE}_id)';
|
||||
command_create_foreign_key_1 TEXT := 'ALTER TABLE {TABLE_NAME} ADD CONSTRAINT {TABLE_NAME}_euid_fkey FOREIGN KEY (euid) REFERENCES edit_user (edit_user_id) MATCH FULL ON UPDATE CASCADE ON DELETE SET NULL';
|
||||
command_create_trigger_1 TEXT = 'CREATE TRIGGER trg_{TABLE_NAME} BEFORE INSERT OR UPDATE ON {TABLE_NAME} FOR EACH ROW EXECUTE PROCEDURE set_edit_generic()';
|
||||
BEGIN
|
||||
-- we are in valid start time area
|
||||
IF (NEW.event_date >= start_date) THEN
|
||||
-- move interval
|
||||
_interval := '1 ' || selector;
|
||||
-- current table name
|
||||
table_name := base_table || to_char(NEW.event_date, timeformat);
|
||||
table_name := base_table || '_' || to_char(NEW.event_date, timeformat);
|
||||
BEGIN
|
||||
EXECUTE 'INSERT INTO ' || quote_ident(table_name) || ' SELECT ($1).*' USING NEW;
|
||||
-- check if next month table exists
|
||||
table_name := base_table || to_char((SELECT NEW.event_date + _interval)::DATE, timeformat);
|
||||
-- RAISE NOTICE 'SEARCH NEXT: %', table_name;
|
||||
IF (SELECT to_regclass(table_name)) IS NULL THEN
|
||||
-- move outer interval
|
||||
_interval_next := '2 ' || selector;
|
||||
-- move inner interval same
|
||||
start_date := date_trunc(selector, NEW.event_date + _interval);
|
||||
end_date := date_trunc(selector, NEW.event_date + _interval_next);
|
||||
-- RAISE NOTICE 'CREATE NEXT: %', table_name;
|
||||
-- create table
|
||||
EXECUTE 'CREATE TABLE IF NOT EXISTS ' || quote_ident(table_name) || ' ( CHECK ( event_date >= ' || quote_literal(start_date) || ' AND event_date < ' || quote_literal(end_date) || ' ) ) INHERITS (edit_log)';
|
||||
-- create all indexes and triggers
|
||||
EXECUTE 'ALTER TABLE ' || quote_ident(table_name) || ' ADD PRIMARY KEY (edit_log_id)';
|
||||
-- FK constraints
|
||||
EXECUTE 'ALTER TABLE ' || quote_ident(table_name) || ' ADD CONSTRAINT fk_' || quote_ident(table_name) || '_euid_fkey FOREIGN KEY (euid) REFERENCES edit_user (edit_user_id) MATCH FULL ON UPDATE CASCADE ON DELETE CASCADE';
|
||||
-- generic trigger
|
||||
EXECUTE 'CREATE TRIGGER trg_' || quote_ident(table_name) || ' BEFORE INSERT OR UPDATE ON ' || quote_ident(table_name) || ' FOR EACH ROW EXECUTE PROCEDURE set_edit_generic()';
|
||||
END IF;
|
||||
-- if insert failed because of missing table, create new below
|
||||
EXCEPTION
|
||||
WHEN undefined_table THEN
|
||||
-- another block, so in case the creation fails here too
|
||||
BEGIN
|
||||
-- create new talbe here + all indexes
|
||||
-- create new table here + all indexes
|
||||
start_date := date_trunc(selector, NEW.event_date);
|
||||
end_date := date_trunc(selector, NEW.event_date + _interval);
|
||||
-- creat table
|
||||
EXECUTE 'CREATE TABLE IF NOT EXISTS ' || quote_ident(table_name) || ' ( CHECK ( event_date >= ' || quote_literal(start_date) || ' AND event_date < ' || quote_literal(end_date) || ' ) ) INHERITS (edit_log)';
|
||||
EXECUTE format(REPLACE( -- end date
|
||||
REPLACE( -- start date
|
||||
REPLACE( -- compare date name
|
||||
REPLACE( -- base name (inherit)
|
||||
REPLACE( -- table name
|
||||
command_create_table,
|
||||
'{TABLE_NAME}',
|
||||
table_name
|
||||
),
|
||||
'{BASE_NAME}',
|
||||
base_table
|
||||
),
|
||||
'{COMPARE_DATE_NAME}',
|
||||
compare_date_name
|
||||
),
|
||||
'{START_DATE}',
|
||||
quote_literal(start_date)
|
||||
),
|
||||
'{END_DATE}',
|
||||
quote_literal(end_date)
|
||||
));
|
||||
-- create all indexes and triggers
|
||||
EXECUTE 'ALTER TABLE ' || quote_ident(table_name) || ' ADD PRIMARY KEY (edit_log_id)';
|
||||
EXECUTE format(REPLACE(
|
||||
REPLACE(
|
||||
command_create_primary_key,
|
||||
'{TABLE_NAME}',
|
||||
table_name
|
||||
),
|
||||
'{BASE_TABLE}',
|
||||
base_table
|
||||
));
|
||||
-- FK constraints
|
||||
EXECUTE 'ALTER TABLE ' || quote_ident(table_name) || ' ADD CONSTRAINT fk_' || quote_ident(table_name) || '_euid_fkey FOREIGN KEY (euid) REFERENCES edit_user (edit_user_id) MATCH FULL ON UPDATE CASCADE ON DELETE CASCADE';
|
||||
EXECUTE format(REPLACE(command_create_foreign_key_1, '{TABLE_NAME}', table_name));
|
||||
-- generic trigger
|
||||
EXECUTE 'CREATE TRIGGER trg_' || quote_ident(table_name) || ' BEFORE INSERT OR UPDATE ON ' || quote_ident(table_name) || ' FOR EACH ROW EXECUTE PROCEDURE set_edit_generic()';
|
||||
EXECUTE format(REPLACE(command_create_trigger_1, '{TABLE_NAME}', table_name));
|
||||
|
||||
-- insert try again
|
||||
EXECUTE 'INSERT INTO ' || quote_ident(table_name) || ' SELECT ($1).*' USING NEW;
|
||||
@@ -74,6 +89,57 @@ BEGIN
|
||||
-- if this faled, throw it into the overflow table (so we don't loose anything)
|
||||
INSERT INTO edit_log_overflow VALUES (NEW.*);
|
||||
END;
|
||||
-- main insert run done, check if we have to create next months table
|
||||
BEGIN
|
||||
-- check if next month table exists
|
||||
table_name := base_table || '_' || to_char((SELECT NEW.event_date + _interval)::DATE, timeformat);
|
||||
-- RAISE NOTICE 'SEARCH NEXT: %', table_name;
|
||||
IF (SELECT to_regclass(table_name)) IS NULL THEN
|
||||
-- move inner interval same
|
||||
start_date := date_trunc(selector, NEW.event_date + _interval);
|
||||
end_date := date_trunc(selector, NEW.event_date + _interval_next);
|
||||
-- RAISE NOTICE 'CREATE NEXT: %', table_name;
|
||||
-- create table
|
||||
EXECUTE format(REPLACE( -- end date
|
||||
REPLACE( -- start date
|
||||
REPLACE( -- compare date name
|
||||
REPLACE( -- base name (inherit)
|
||||
REPLACE( -- table name
|
||||
command_create_table,
|
||||
'{TABLE_NAME}',
|
||||
table_name
|
||||
),
|
||||
'{BASE_NAME}',
|
||||
base_table
|
||||
),
|
||||
'{COMPARE_DATE_NAME}',
|
||||
compare_date_name
|
||||
),
|
||||
'{START_DATE}',
|
||||
quote_literal(start_date)
|
||||
),
|
||||
'{END_DATE}',
|
||||
quote_literal(end_date)
|
||||
));
|
||||
-- create all indexes and triggers
|
||||
EXECUTE format(REPLACE(
|
||||
REPLACE(
|
||||
command_create_primary_key,
|
||||
'{TABLE_NAME}',
|
||||
table_name
|
||||
),
|
||||
'{BASE_TABLE}',
|
||||
base_table
|
||||
));
|
||||
-- FK constraints
|
||||
EXECUTE format(REPLACE(command_create_foreign_key_1, '{TABLE_NAME}', table_name));
|
||||
-- generic trigger
|
||||
EXECUTE format(REPLACE(command_create_trigger_1, '{TABLE_NAME}', table_name));
|
||||
END IF;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
RAISE NOTICE 'Failed to create next table: %', table_name;
|
||||
END;
|
||||
ELSE
|
||||
-- if outside valid date, insert into overflow
|
||||
INSERT INTO edit_log_overflow VALUES (NEW.*);
|
||||
|
||||
@@ -37,5 +37,5 @@ CREATE TABLE edit_log (
|
||||
http_accept_charset VARCHAR,
|
||||
http_accept_encoding VARCHAR,
|
||||
session_id VARCHAR,
|
||||
FOREIGN KEY (euid) REFERENCES edit_user (edit_user_id) MATCH FULL ON UPDATE CASCADE
|
||||
FOREIGN KEY (euid) REFERENCES edit_user (edit_user_id) MATCH FULL ON UPDATE CASCADE ON DELETE SET NULL
|
||||
) INHERITS (edit_generic) WITHOUT OIDS;
|
||||
|
||||
12
4dev/database/table/edit_log_overflow.sql
Executable file
12
4dev/database/table/edit_log_overflow.sql
Executable file
@@ -0,0 +1,12 @@
|
||||
-- AUTHOR: Clemens Schwaighofer
|
||||
-- DATE: 2020/1/28
|
||||
-- DESCRIPTION:
|
||||
-- edit log overflow table
|
||||
-- this is the overflow table for partition
|
||||
-- TABLE: edit_log_overflow
|
||||
-- HISTORY:
|
||||
|
||||
-- DROP TABLE edit_log_overflow;
|
||||
CREATE TABLE IF NOT EXISTS edit_log_overflow () INHERITS (edit_log);
|
||||
ALTER TABLE edit_log_overflow ADD PRIMARY KEY (edit_log_id);
|
||||
ALTER TABLE edit_log_overflow ADD CONSTRAINT edit_log_overflow_euid_fkey FOREIGN KEY (euid) REFERENCES edit_user (edit_user_id) MATCH FULL ON UPDATE CASCADE ON DELETE SET NULL;
|
||||
4
4dev/database/trigger/trg_edit_log_overflow.sql
Executable file
4
4dev/database/trigger/trg_edit_log_overflow.sql
Executable file
@@ -0,0 +1,4 @@
|
||||
DROP TRIGGER IF EXISTS trg_edit_log_overflow ON edit_log_overflow;
|
||||
CREATE TRIGGER trg_edit_log_overflow
|
||||
BEFORE INSERT OR UPDATE ON edit_log_overflow
|
||||
FOR EACH ROW EXECUTE PROCEDURE set_edit_generic();
|
||||
@@ -2045,7 +2045,7 @@ class Basic
|
||||
* returns int/bool in:
|
||||
* -1 if the first date is smaller the last
|
||||
* 0 if both are equal
|
||||
* 1 if the end date is bigger than the last
|
||||
* 1 if the first date is bigger than the last
|
||||
* false if no valid date/times chould be found
|
||||
* @param string $start_datetime start date/time in YYYY-MM-DD HH:mm:ss
|
||||
* @param string $end_datetime end date/time in YYYY-MM-DD HH:mm:ss
|
||||
|
||||
Reference in New Issue
Block a user