From e30f459131a133ec4f1d75e619dca85b49aae6a3 Mon Sep 17 00:00:00 2001 From: Jason Teng Date: Wed, 18 Dec 2024 13:07:51 -0500 Subject: [PATCH] Disallow the use of user-defined functions in column defaults for temp tables and table variables. In SQL Server, it is prohibited for users to use user-defined functions as column defaults in temp tables and table variables - the only exception is in the tempdb database, but this is not currently even supported in Babelfish, so for now we will impose the same restrictions as exist elsewhere in SQL Server. Task: BABEL-4868 Signed-off-by: Jason Teng Signed-off-by: Tim Chang Co-authored-by: Jason Teng Co-authored-by: Tim Chang --- contrib/babelfishpg_tsql/src/pl_handler.c | 100 +++++++++- test/JDBC/expected/temp_table.out | 210 +++++++++++++++++++++ test/JDBC/input/temp_tables/temp_table.sql | 131 +++++++++++++ 3 files changed, 436 insertions(+), 5 deletions(-) diff --git a/contrib/babelfishpg_tsql/src/pl_handler.c b/contrib/babelfishpg_tsql/src/pl_handler.c index a49c0f8d5c..1c288cc376 100644 --- a/contrib/babelfishpg_tsql/src/pl_handler.c +++ b/contrib/babelfishpg_tsql/src/pl_handler.c @@ -149,7 +149,9 @@ extern bool pltsql_check_guc_plan(CachedPlanSource *plansource); bool pltsql_function_as_checker(const char *lang, List *as, char **prosrc_str_p, char **probin_str_p); extern void pltsql_function_probin_writer(CreateFunctionStmt *stmt, Oid languageOid, char **probin_str_p); extern void pltsql_function_probin_reader(ParseState *pstate, List *fargs, Oid *actual_arg_types, Oid *declared_arg_types, Oid funcid); -static void check_nullable_identity_constraint(RangeVar *relation, ColumnDef *column); +static void check_invalid_column_constraints(RangeVar *relation, ColumnDef *column); +static void check_invalid_constraints(RangeVar *relation, Constraint *constraint); +static bool checkAndSetTsqlSystemFunc(FuncCall *fc); static bool is_identity_constraint(ColumnDef *column); extern PLtsql_function *find_cached_batch(int handle); extern void apply_post_compile_actions(PLtsql_function *func, InlineCodeBlockArgs *args); @@ -1089,7 +1091,7 @@ pltsql_post_parse_analyze(ParseState *pstate, Query *query, JumbleState *jstate) switch (nodeTag(element)) { case T_ColumnDef: - check_nullable_identity_constraint(stmt->relation, + check_invalid_column_constraints(stmt->relation, (ColumnDef *) element); if (is_identity_constraint((ColumnDef *) element)) { @@ -1176,7 +1178,7 @@ pltsql_post_parse_analyze(ParseState *pstate, Query *query, JumbleState *jstate) switch (cmd->subtype) { case AT_AddColumn: - check_nullable_identity_constraint(atstmt->relation, + check_invalid_column_constraints(atstmt->relation, castNode(ColumnDef, cmd->def)); if (is_identity_constraint(castNode(ColumnDef, cmd->def))) { @@ -1204,6 +1206,8 @@ pltsql_post_parse_analyze(ParseState *pstate, Query *query, JumbleState *jstate) { Constraint *c = castNode(Constraint, cmd->def); + check_invalid_constraints(atstmt->relation, c); + if (rowversion_column_name) validate_rowversion_table_constraint(c, rowversion_column_name); } @@ -1254,6 +1258,17 @@ pltsql_post_parse_analyze(ParseState *pstate, Query *query, JumbleState *jstate) { int colnamelen = strlen(cmd->name); + if (nodeTag(cmd->def) == T_FuncCall) + { + if (atstmt->relation->relpersistence == RELPERSISTENCE_TEMP && + !checkAndSetTsqlSystemFunc(castNode(FuncCall, cmd->def))) + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_COLUMN_DEFINITION), + errmsg("User-defined functions, partition functions, and column references are not allowed in expressions in this context."))); + } + } + /* * Disallow defaults on a rowversion * column. @@ -1907,9 +1922,13 @@ revoke_type_permission_from_public(PlannedStmt *pstmt, const char *queryString, CommandCounterIncrement(); } - +/* + * Check for constraints that are invalid in TSQL. For example: + * 1. Identity columns cannot be nullable + * 2. User-defined functions (UDFs) are not allowed in TSQL temp table or table variable column defaults. + */ static void -check_nullable_identity_constraint(RangeVar *relation, ColumnDef *column) +check_invalid_column_constraints(RangeVar *relation, ColumnDef *column) { ListCell *clist; bool is_null = false; @@ -1918,6 +1937,7 @@ check_nullable_identity_constraint(RangeVar *relation, ColumnDef *column) foreach(clist, column->constraints) { Constraint *constraint = lfirst_node(Constraint, clist); + check_invalid_constraints(relation, constraint); switch (constraint->contype) { @@ -1942,6 +1962,76 @@ check_nullable_identity_constraint(RangeVar *relation, ColumnDef *column) relation->relname))); } +/* + * Similar to check_invalid_column_constraints, but for individual constraints, such as added by + * ALTER TABLE ADD CONSTRAINT + */ +static void +check_invalid_constraints(RangeVar *relation, Constraint *constraint) +{ + switch (constraint->contype) + { + case CONSTR_DEFAULT: + { + if (IsA(constraint->raw_expr, FuncCall)) + { + FuncCall *fc = castNode(FuncCall, constraint->raw_expr); + if (relation->relpersistence == RELPERSISTENCE_TEMP && !checkAndSetTsqlSystemFunc(fc)) + { + ereport(ERROR, + (errcode(ERRCODE_INVALID_COLUMN_DEFINITION), + errmsg("User-defined functions, partition functions, and column references are not allowed in expressions in this context."))); + } + } + break; + } + + default: + break; + } +} + +/* + * Returns true iff the function is a system function. For Babelfish, this means searching in the "sys" + * schema, but the "sys" schema is meant to be opaque to customers, so to match SQL Server behavior + * we assume that it will never be schema-qualified in order to be true. + * If we do find a matching system function, then we modify the func call to explicitly call the fully-qualified + * system function, to prevent inadvertently using any user-defined overrides for the function name. + */ +static bool +checkAndSetTsqlSystemFunc(FuncCall *fc) +{ + List *name_to_search; + ObjectWithArgs *owa = makeNode(ObjectWithArgs); + char *sys = palloc0(4); + strncpy(sys, "sys", 3); + if (list_length(fc->funcname) == 1) + { + /* explicitly search in the "sys" schema */ + name_to_search = list_make2(makeString(sys), linitial(fc->funcname)); + } + else + { + ereport(ERROR, + (errcode(ERRCODE_UNDEFINED_COLUMN), + errmsg("Column \"%s\" is not allowed in this context, and the user-defined function or aggregate \"%s\" could not be found.", + strVal(linitial(fc->funcname)), + NameListToString(fc->funcname)))); + } + + owa->objname = name_to_search; + owa->args_unspecified = true; + + if (LookupFuncWithArgs(OBJECT_FUNCTION, owa, true)) + { + list_free(fc->funcname); + fc->funcname = name_to_search; + return true; + } + + return false; +} + static void pltsql_sequence_validate_increment(int64 increment_by, int64 max_value, diff --git a/test/JDBC/expected/temp_table.out b/test/JDBC/expected/temp_table.out index 3a65d23ee7..7de7719c7a 100644 --- a/test/JDBC/expected/temp_table.out +++ b/test/JDBC/expected/temp_table.out @@ -1,3 +1,6 @@ +USE master +GO + -- BABEL-4912 test ALTER TABLE for temp tables CREATE TABLE #t1 (a INT IDENTITY PRIMARY KEY NOT NULL, b INT) GO @@ -258,3 +261,210 @@ int DROP TABLE #t1 GO + +-- BABEL-4868 disallow the usage of user-defined functions in temp table column defaults (to prevent orphaned catalog entries) +CREATE FUNCTION temp_table_func1(@a INT) RETURNS INT AS BEGIN RETURN 1 END +GO + +-- normal tables should be ok +CREATE TABLE temp_table_t1(a INT DEFAULT temp_table_func1(5)) +GO + +INSERT INTO temp_table_t1 VALUES (DEFAULT) +GO +~~ROW COUNT: 1~~ + + +SELECT * FROM temp_table_t1 +GO +~~START~~ +int +1 +~~END~~ + + +DROP TABLE temp_table_t1 +GO + +-- temp tables should not work +CREATE TABLE #t1 (a INT DEFAULT temp_table_func1(5)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: User-defined functions, partition functions, and column references are not allowed in expressions in this context.)~~ + + +-- two and three part names should not work either +CREATE TABLE #t1 (a INT DEFAULT dbo.temp_table_func1(6)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Column "master_dbo" is not allowed in this context, and the user-defined function or aggregate "master_dbo.temp_table_func1" could not be found.)~~ + + +CREATE TABLE #t1 (a INT DEFAULT master.dbo.temp_table_func1(7)) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Column "master_dbo" is not allowed in this context, and the user-defined function or aggregate "master_dbo.temp_table_func1" could not be found.)~~ + + +-- also block adding columns via ALTER TABLE +CREATE TABLE #t1 (a INT) +GO + +ALTER TABLE #t1 ADD b INT DEFAULT temp_table_func1(5) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: User-defined functions, partition functions, and column references are not allowed in expressions in this context.)~~ + + +DROP TABLE #t1 +GO + +-- same with table variables +DECLARE @tv TABLE (a INT DEFAULT temp_table_func1(5)) +INSERT INTO @tv VALUES (DEFAULT) +SELECT * FROM @tv +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: User-defined functions, partition functions, and column references are not allowed in expressions in this context.)~~ + + +-- system functions such as ISJSON() should work +CREATE TABLE #t1 (a INT DEFAULT ISJSON('a')) +GO + +ALTER TABLE #t1 ADD b INT DEFAULT ISJSON('b') +GO + +INSERT INTO #t1 VALUES (DEFAULT, DEFAULT) +GO +~~ROW COUNT: 1~~ + + +SELECT * FROM #t1 +GO +~~START~~ +int#!#int +0#!#0 +~~END~~ + + +DROP TABLE #t1 +GO + +DECLARE @tv TABLE (a INT DEFAULT ISJSON('a')) +INSERT INTO @tv VALUES (DEFAULT) +SELECT * FROM @tv +GO +~~ROW COUNT: 1~~ + +~~START~~ +int +0 +~~END~~ + + +-- disallow "sys"-qualified function calls +CREATE TABLE #t1 (a INT DEFAULT SYS.ISJSON('a')) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Column "sys" is not allowed in this context, and the user-defined function or aggregate "sys.isjson" could not be found.)~~ + + +-- disallow user-defined overrides for system functions +CREATE FUNCTION ISJSON(@json TEXT) RETURNS INT AS BEGIN RETURN 10 END +GO + +-- cannot use schema-qualified name +CREATE TABLE #t1 (a INT DEFAULT dbo.ISJSON('a')) +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Column "master_dbo" is not allowed in this context, and the user-defined function or aggregate "master_dbo.isjson" could not be found.)~~ + + +-- should work, default to using the system function +CREATE TABLE #t1 (a INT DEFAULT ISJSON('a')) +GO + +INSERT INTO #t1 VALUES (DEFAULT) +GO +~~ROW COUNT: 1~~ + + +SELECT * FROM #t1 +GO +~~START~~ +int +0 +~~END~~ + + +DROP TABLE #t1 +GO + +-- Aggregate functions should not work +create table #t1(a int, b int default any_value(a)) +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: User-defined functions, partition functions, and column references are not allowed in expressions in this context.)~~ + + +create table #t1(a int, b int default any_value(1)) +go +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: User-defined functions, partition functions, and column references are not allowed in expressions in this context.)~~ + + +-- also validate that the restrictions work for ALTER TABLE ADD CONSTRAINT +CREATE TABLE #t1 (a INT) +GO + +-- user-defined functions should not work +ALTER TABLE #t1 ADD CONSTRAINT myconstraint DEFAULT temp_table_func1(5) FOR a +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: User-defined functions, partition functions, and column references are not allowed in expressions in this context.)~~ + + +-- nor should system function overrides +ALTER TABLE #t1 ADD CONSTRAINT myconstraint DEFAULT dbo.ISJSON('a') FOR a +GO +~~ERROR (Code: 33557097)~~ + +~~ERROR (Message: Column "master_dbo" is not allowed in this context, and the user-defined function or aggregate "master_dbo.isjson" could not be found.)~~ + + +-- but system functions should still work +ALTER TABLE #t1 ADD CONSTRAINT myconstraint DEFAULT ISJSON('a') FOR a +GO + +INSERT INTO #t1 VALUES (DEFAULT) +GO +~~ROW COUNT: 1~~ + + +SELECT * FROM #t1 +GO +~~START~~ +int +0 +~~END~~ + + +DROP TABLE #t1 +GO + +DROP FUNCTION dbo.ISJSON +GO + +DROP FUNCTION temp_table_func1 +GO diff --git a/test/JDBC/input/temp_tables/temp_table.sql b/test/JDBC/input/temp_tables/temp_table.sql index 697ab44617..203436a6ed 100644 --- a/test/JDBC/input/temp_tables/temp_table.sql +++ b/test/JDBC/input/temp_tables/temp_table.sql @@ -1,3 +1,6 @@ +USE master +GO + -- BABEL-4912 test ALTER TABLE for temp tables CREATE TABLE #t1 (a INT IDENTITY PRIMARY KEY NOT NULL, b INT) GO @@ -163,3 +166,131 @@ GO DROP TABLE #t1 GO + +-- BABEL-4868 disallow the usage of user-defined functions in temp table column defaults (to prevent orphaned catalog entries) +CREATE FUNCTION temp_table_func1(@a INT) RETURNS INT AS BEGIN RETURN 1 END +GO + +-- normal tables should be ok +CREATE TABLE temp_table_t1(a INT DEFAULT temp_table_func1(5)) +GO + +INSERT INTO temp_table_t1 VALUES (DEFAULT) +GO + +SELECT * FROM temp_table_t1 +GO + +DROP TABLE temp_table_t1 +GO + +-- temp tables should not work +CREATE TABLE #t1 (a INT DEFAULT temp_table_func1(5)) +GO + +-- two and three part names should not work either +CREATE TABLE #t1 (a INT DEFAULT dbo.temp_table_func1(6)) +GO + +CREATE TABLE #t1 (a INT DEFAULT master.dbo.temp_table_func1(7)) +GO + +-- also block adding columns via ALTER TABLE +CREATE TABLE #t1 (a INT) +GO + +ALTER TABLE #t1 ADD b INT DEFAULT temp_table_func1(5) +GO + +DROP TABLE #t1 +GO + +-- same with table variables +DECLARE @tv TABLE (a INT DEFAULT temp_table_func1(5)) +INSERT INTO @tv VALUES (DEFAULT) +SELECT * FROM @tv +GO + +-- system functions such as ISJSON() should work +CREATE TABLE #t1 (a INT DEFAULT ISJSON('a')) +GO + +ALTER TABLE #t1 ADD b INT DEFAULT ISJSON('b') +GO + +INSERT INTO #t1 VALUES (DEFAULT, DEFAULT) +GO + +SELECT * FROM #t1 +GO + +DROP TABLE #t1 +GO + +DECLARE @tv TABLE (a INT DEFAULT ISJSON('a')) +INSERT INTO @tv VALUES (DEFAULT) +SELECT * FROM @tv +GO + +-- disallow "sys"-qualified function calls +CREATE TABLE #t1 (a INT DEFAULT SYS.ISJSON('a')) +GO + +-- disallow user-defined overrides for system functions +CREATE FUNCTION ISJSON(@json TEXT) RETURNS INT AS BEGIN RETURN 10 END +GO + +-- cannot use schema-qualified name +CREATE TABLE #t1 (a INT DEFAULT dbo.ISJSON('a')) +GO + +-- should work, default to using the system function +CREATE TABLE #t1 (a INT DEFAULT ISJSON('a')) +GO + +INSERT INTO #t1 VALUES (DEFAULT) +GO + +SELECT * FROM #t1 +GO + +DROP TABLE #t1 +GO + +-- Aggregate functions should not work +create table #t1(a int, b int default any_value(a)) +go + +create table #t1(a int, b int default any_value(1)) +go + +-- also validate that the restrictions work for ALTER TABLE ADD CONSTRAINT +CREATE TABLE #t1 (a INT) +GO + +-- user-defined functions should not work +ALTER TABLE #t1 ADD CONSTRAINT myconstraint DEFAULT temp_table_func1(5) FOR a +GO + +-- nor should system function overrides +ALTER TABLE #t1 ADD CONSTRAINT myconstraint DEFAULT dbo.ISJSON('a') FOR a +GO + +-- but system functions should still work +ALTER TABLE #t1 ADD CONSTRAINT myconstraint DEFAULT ISJSON('a') FOR a +GO + +INSERT INTO #t1 VALUES (DEFAULT) +GO + +SELECT * FROM #t1 +GO + +DROP TABLE #t1 +GO + +DROP FUNCTION dbo.ISJSON +GO + +DROP FUNCTION temp_table_func1 +GO