Skip to content

Commit

Permalink
Support Instead of Trigger On Views (babelfish-for-postgresql#2158)
Browse files Browse the repository at this point in the history
Currently Postgres does not support Instead of Trigger On Views for DML
queries.

On running such a query on VIEW, query rewriting substitutes view with
underlying base table.
Added a hook for skipping the substitution for DML query on the VIEW.

This change will add support for Instead of Triggers for DML queries
when using Babelfish.

Task: BABEL-2170/BABEL-4532/BABEL-4514
Signed-off-by: Deepakshi Mittal <[email protected]>
  • Loading branch information
deepakshi-mittal committed Jan 3, 2024
1 parent ef84a49 commit cbaece4
Show file tree
Hide file tree
Showing 31 changed files with 1,764 additions and 0 deletions.
61 changes: 61 additions & 0 deletions contrib/babelfishpg_tsql/src/hooks.c
Original file line number Diff line number Diff line change
Expand Up @@ -159,6 +159,7 @@ static void pltsql_ExecutorStart(QueryDesc *queryDesc, int eflags);
static void pltsql_ExecutorRun(QueryDesc *queryDesc, ScanDirection direction, uint64 count, bool execute_once);
static void pltsql_ExecutorFinish(QueryDesc *queryDesc);
static void pltsql_ExecutorEnd(QueryDesc *queryDesc);
static bool pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event);

static bool plsql_TriggerRecursiveCheck(ResultRelInfo *resultRelInfo);
static bool bbf_check_rowcount_hook(int es_processed);
Expand Down Expand Up @@ -210,6 +211,7 @@ static ExecutorFinish_hook_type prev_ExecutorFinish = NULL;
static ExecutorEnd_hook_type prev_ExecutorEnd = NULL;
static GetNewObjectId_hook_type prev_GetNewObjectId_hook = NULL;
static inherit_view_constraints_from_table_hook_type prev_inherit_view_constraints_from_table = NULL;
static bbfViewHasInsteadofTrigger_hook_type prev_bbfViewHasInsteadofTrigger_hook = NULL;
static detect_numeric_overflow_hook_type prev_detect_numeric_overflow_hook = NULL;
static match_pltsql_func_call_hook_type prev_match_pltsql_func_call_hook = NULL;
static insert_pltsql_function_defaults_hook_type prev_insert_pltsql_function_defaults_hook = NULL;
Expand Down Expand Up @@ -325,6 +327,9 @@ InstallExtendedHooks(void)
inherit_view_constraints_from_table_hook = preserve_view_constraints_from_base_table;
TriggerRecuresiveCheck_hook = plsql_TriggerRecursiveCheck;

prev_bbfViewHasInsteadofTrigger_hook = bbfViewHasInsteadofTrigger_hook;
bbfViewHasInsteadofTrigger_hook = pltsql_bbfViewHasInsteadofTrigger;

prev_detect_numeric_overflow_hook = detect_numeric_overflow_hook;
detect_numeric_overflow_hook = pltsql_detect_numeric_overflow;

Expand Down Expand Up @@ -434,6 +439,7 @@ UninstallExtendedHooks(void)
ExecutorEnd_hook = prev_ExecutorEnd;
GetNewObjectId_hook = prev_GetNewObjectId_hook;
inherit_view_constraints_from_table_hook = prev_inherit_view_constraints_from_table;
bbfViewHasInsteadofTrigger_hook = prev_bbfViewHasInsteadofTrigger_hook;
detect_numeric_overflow_hook = prev_detect_numeric_overflow_hook;
match_pltsql_func_call_hook = prev_match_pltsql_func_call_hook;
insert_pltsql_function_defaults_hook = prev_insert_pltsql_function_defaults_hook;
Expand Down Expand Up @@ -713,6 +719,61 @@ plsql_TriggerRecursiveCheck(ResultRelInfo *resultRelInfo)
return false;
}

/**
* Hook function to skip rewriting VIEW with base table if the VIEW has an instead of trigger
* Checks if view have an INSTEAD OF trigger at statement level
* If it does, we don't want to treat it as auto-updatable.
* This function also does error checking for recursive triggers
* Reference - src/backend/rewrite/rewriteHandler.c view_has_instead_trigger
*/
static bool
pltsql_bbfViewHasInsteadofTrigger(Relation view, CmdType event)
{
TriggerDesc *trigDesc = view->trigdesc;
if (trigDesc && triggerInvocationSequence)
{
int i;
for (i = 0; i < trigDesc->numtriggers; i++)
{
Trigger *trigger = &trigDesc->triggers[i];
Oid current_tgoid = trigger->tgoid;
Oid prev_tgoid = InvalidOid;
prev_tgoid = lfirst_oid(list_tail(triggerInvocationSequence));
if (prev_tgoid == current_tgoid)
{
return false; /** Loop trigger call by itself*/
}
else if (list_length(triggerInvocationSequence) > TRIGGER_MAX_NEST_LEVEL || list_member_oid(triggerInvocationSequence, current_tgoid))
{
/** Loop trigger call by another trigger */
ereport(ERROR,
(errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED),
errmsg("Maximum stored procedure, function, trigger, or view nesting level exceeded (limit %d)", TRIGGER_MAX_NEST_LEVEL)));
}
}
}

switch (event)
{
case CMD_INSERT:
if (trigDesc && trigDesc->trig_insert_instead_statement)
return true;
break;
case CMD_UPDATE:
if (trigDesc && trigDesc->trig_update_instead_statement)
return true;
break;
case CMD_DELETE:
if (trigDesc && trigDesc->trig_delete_instead_statement)
return true;
break;
default:
elog(ERROR, "unrecognized CmdType: %d", (int)event);
break;
}
return false;
}

/*
* Wrapper function that calls the initilization function.
* Calls the pre function call hook on the procname
Expand Down
2 changes: 2 additions & 0 deletions contrib/babelfishpg_tsql/src/pltsql.h
Original file line number Diff line number Diff line change
Expand Up @@ -62,6 +62,8 @@
/* Max number of Args allowed for Prepared stmts. */
#define PREPARE_STMT_MAX_ARGS 2100

#define TRIGGER_MAX_NEST_LEVEL 32 /* Maximum allowed trigger nesting level*/

/*
* Compiler's namespace item types
*/
Expand Down
39 changes: 39 additions & 0 deletions test/JDBC/expected/BABEL-2170-vu-cleanup.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
-- clean all objects in first database
USE babel_2170_db1;
GO

DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_insert;
GO

DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_update;
GO

DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_delete;
GO

DROP TRIGGER IF EXISTS babel_2170_vu_employees_view_iot_bulkinsert;
GO

DROP VIEW IF EXISTS babel_2170_vu_employees_view;
GO

DROP VIEW IF EXISTS babel_2170_vu_employees_view_bulkinsert;
GO

DROP VIEW IF EXISTS babel_2170_vu_employees_view_2;
GO

DROP TABLE IF EXISTS babel_2170_vu_employees;
GO

DROP VIEW IF EXISTS babel_2170_vu_employees_view_txn;
GO

DROP TABLE IF EXISTS babel_2170_vu_employees_txn;
GO

USE MASTER;
GO

DROP DATABASE IF EXISTS babel_2170_db1;
GO
104 changes: 104 additions & 0 deletions test/JDBC/expected/BABEL-2170-vu-prepare.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,104 @@
CREATE DATABASE babel_2170_db1;
GO

USE babel_2170_db1;
GO

CREATE TABLE babel_2170_vu_employees
(
EmployeeID int NOT NULL,
EmployeeName VARCHAR(50),
EmployeeAddress VARCHAR(50),
MonthSalary NUMERIC(10, 2)
)
GO

INSERT INTO babel_2170_vu_employees VALUES(1, 'amber', '1st Street', '1000');
INSERT INTO babel_2170_vu_employees VALUES(2, 'angel', '1st Street', '2000');
GO
~~ROW COUNT: 1~~

~~ROW COUNT: 1~~


CREATE VIEW babel_2170_vu_employees_view AS
SELECT EmployeeID,
EmployeeName,
EmployeeAddress,
MonthSalary
FROM babel_2170_vu_employees
WHERE EmployeeName LIKE 'a%';
GO

CREATE VIEW babel_2170_vu_employees_view_bulkinsert AS
SELECT EmployeeID,
EmployeeName,
EmployeeAddress,
MonthSalary
FROM babel_2170_vu_employees
WHERE EmployeeName LIKE 'b%';
GO

CREATE VIEW babel_2170_vu_employees_view_2 AS
SELECT EmployeeID,
EmployeeName,
EmployeeAddress,
MonthSalary
FROM babel_2170_vu_employees
WHERE EmployeeName LIKE 'a%';
GO

CREATE SCHEMA schema_2170;
GO

CREATE TABLE schema_2170.babel_2170_vu_employees
(
EmployeeID int NOT NULL,
EmployeeName VARCHAR(50),
EmployeeAddress VARCHAR(50),
MonthSalary NUMERIC(10, 2)
)
GO

INSERT INTO schema_2170.babel_2170_vu_employees VALUES(1, 'amber', '1st Street', '1000');
INSERT INTO schema_2170.babel_2170_vu_employees VALUES(2, 'angel', '1st Street', '2000');
GO
~~ROW COUNT: 1~~

~~ROW COUNT: 1~~


CREATE VIEW schema_2170.babel_2170_vu_employees_view AS
SELECT EmployeeID,
EmployeeName,
EmployeeAddress,
MonthSalary
FROM schema_2170.babel_2170_vu_employees
WHERE EmployeeName LIKE 'a%';
GO

CREATE TABLE babel_2170_vu_employees_txn
(
EmployeeID int NOT NULL,
EmployeeName VARCHAR(50),
EmployeeAddress VARCHAR(50),
MonthSalary NUMERIC(10, 2)
)
GO

INSERT INTO babel_2170_vu_employees_txn VALUES(1, 'amber', '1st Street', '1000');
INSERT INTO babel_2170_vu_employees_txn VALUES(2, 'angel', '1st Street', '2000');
GO
~~ROW COUNT: 1~~

~~ROW COUNT: 1~~


CREATE VIEW babel_2170_vu_employees_view_txn AS
SELECT EmployeeID,
EmployeeName,
EmployeeAddress,
MonthSalary
FROM babel_2170_vu_employees_txn
WHERE EmployeeName LIKE 'a%';
GO
Loading

0 comments on commit cbaece4

Please sign in to comment.