From 0f02545dbb667b8e53e8b053650a4581207a7db9 Mon Sep 17 00:00:00 2001 From: Carlos Ruiz Date: Mon, 10 Jun 2024 13:11:42 +0200 Subject: [PATCH] IDEMPIERE-6166 PostgreSQL DUAL table with more than one record (#2387) * IDEMPIERE-6166 PostgreSQL DUAL table with more than one record - create unique index on dual.dummy for postgresql * - implement suggestion from hengsin - make dual a view instead of a table - fix similar issue with the table dbreplicasyncverifier - it must ensure to contain just one table - running again a COPY command must fail --- .../functions/dbreplicasyncverifier.sql | 29 ++++++++++++++++++ .../functions/register_migration_script.sql | 11 ++----- .../oracle/202406072107_IDEMPIERE-6166.sql | 5 ++++ .../202406072107_IDEMPIERE-6166.sql | 30 +++++++++++++++++++ 4 files changed, 66 insertions(+), 9 deletions(-) create mode 100644 db/postgresql/functions/dbreplicasyncverifier.sql create mode 100644 migration/iD11/oracle/202406072107_IDEMPIERE-6166.sql create mode 100644 migration/iD11/postgresql/202406072107_IDEMPIERE-6166.sql diff --git a/db/postgresql/functions/dbreplicasyncverifier.sql b/db/postgresql/functions/dbreplicasyncverifier.sql new file mode 100644 index 0000000000..f02a615e22 --- /dev/null +++ b/db/postgresql/functions/dbreplicasyncverifier.sql @@ -0,0 +1,29 @@ +/* +CREATE TABLE dbreplicasyncverifier (lastupdate date) +; + +INSERT INTO dbreplicasyncverifier values (to_date('1900-01-01 00:00:00', 'yyyy-mm-dd HH24:MI:SS')) +; +*/ + +CREATE OR REPLACE FUNCTION forbid_multiple_rows_in_dbreplicasyncverifier() +RETURNS TRIGGER AS $$ +BEGIN + -- Check if the table already contains a row + IF (SELECT COUNT(*) FROM dbreplicasyncverifier) > 0 THEN + RAISE EXCEPTION 'Table can only contain one row.'; + END IF; + RETURN NEW; +END; +$$ LANGUAGE plpgsql +; + +CREATE TRIGGER single_row_only_trigger_dbreplicasyncverifier +BEFORE INSERT ON dbreplicasyncverifier +FOR EACH ROW +EXECUTE FUNCTION forbid_multiple_rows_in_dbreplicasyncverifier() +; + +CREATE OR REPLACE RULE delete_dbreplicasyncverifier AS ON DELETE TO dbreplicasyncverifier DO INSTEAD NOTHING +; + diff --git a/db/postgresql/functions/register_migration_script.sql b/db/postgresql/functions/register_migration_script.sql index 4d07a06bc4..5133534159 100644 --- a/db/postgresql/functions/register_migration_script.sql +++ b/db/postgresql/functions/register_migration_script.sql @@ -41,13 +41,6 @@ END; $BODY$ LANGUAGE plpgsql; -CREATE TABLE dual ( dummy char ); - -INSERT INTO dual values ( 'X' ); - -CREATE OR REPLACE RULE insert_dual AS ON INSERT TO dual DO INSTEAD NOTHING; - -CREATE OR REPLACE RULE update_dual AS ON UPDATE TO dual DO INSTEAD NOTHING; - -CREATE OR REPLACE RULE delete_dual AS ON DELETE TO dual DO INSTEAD NOTHING; +CREATE VIEW dual AS SELECT 'X'::varchar AS dummy +; diff --git a/migration/iD11/oracle/202406072107_IDEMPIERE-6166.sql b/migration/iD11/oracle/202406072107_IDEMPIERE-6166.sql new file mode 100644 index 0000000000..fe015d0e68 --- /dev/null +++ b/migration/iD11/oracle/202406072107_IDEMPIERE-6166.sql @@ -0,0 +1,5 @@ +-- IDEMPIERE-6166 PostgreSQL DUAL table with more than one record +SELECT register_migration_script('202406072107_IDEMPIERE-6166.sql') FROM dual; + +-- placeholder, this is just required for postgresql + diff --git a/migration/iD11/postgresql/202406072107_IDEMPIERE-6166.sql b/migration/iD11/postgresql/202406072107_IDEMPIERE-6166.sql new file mode 100644 index 0000000000..9d12bb5b3d --- /dev/null +++ b/migration/iD11/postgresql/202406072107_IDEMPIERE-6166.sql @@ -0,0 +1,30 @@ +-- IDEMPIERE-6166 PostgreSQL DUAL table with more than one record +SELECT register_migration_script('202406072107_IDEMPIERE-6166.sql') FROM dual; + +DROP TABLE IF EXISTS dual +; + +CREATE VIEW dual AS SELECT 'X'::varchar AS dummy +; + +DROP RULE insert_dbreplicasyncverifier ON dbreplicasyncverifier +; + +CREATE OR REPLACE FUNCTION forbid_multiple_rows_in_dbreplicasyncverifier() +RETURNS TRIGGER AS $$ +BEGIN + -- Check if the table already contains a row + IF (SELECT COUNT(*) FROM dbreplicasyncverifier) > 0 THEN + RAISE EXCEPTION 'Table dbreplicasyncverifier can only contain one row.'; + END IF; + RETURN NEW; +END; +$$ LANGUAGE plpgsql +; + +CREATE TRIGGER single_row_only_trigger_dbreplicasyncverifier +BEFORE INSERT ON dbreplicasyncverifier +FOR EACH ROW +EXECUTE FUNCTION forbid_multiple_rows_in_dbreplicasyncverifier() +; +