Skip to content

Commit

Permalink
Do not allow sp_ procedure calls in a SQL function (#3126)
Browse files Browse the repository at this point in the history
T-SQL does not allow calling a stored procedure in a user-defined SQL function and will raise an execution-time error when such an execution is attempted. Babelfish currently enforces this for regular stored procedures, but not for system stored procedures (those whose names start with sp_). Some Babelfish releases ago, executing a system stored procedure in a function would crash the PG server, though in the latest codeline this may just raise an error like InstrStartNode called twice in a row.
The reason is simply that the check in exec_stmt_exec() does not cover the case of a call to a system stored procedure, therefore this fix adds this check to exec_stmt_exec_sp() as well.

NB. This is an execution-time check, presumably because SQL Server allows so-called extended stored procedures (named xp_something) to be called from functions, and these can also be called through a variable -- though neither variable procedure names nor extended stored procedures are currently supported in Babelfish.

Task: BABEL-1730

Signed-off-by: Rob Verschoor [email protected]
  • Loading branch information
robverschoor authored Nov 19, 2024
1 parent 54e28aa commit 5c3ff29
Show file tree
Hide file tree
Showing 8 changed files with 604 additions and 1 deletion.
10 changes: 9 additions & 1 deletion contrib/babelfishpg_tsql/src/pl_exec-2.c
Original file line number Diff line number Diff line change
Expand Up @@ -945,7 +945,7 @@ exec_stmt_exec(PLtsql_execstate *estate, PLtsql_stmt_exec *stmt)

stmt->is_scalar_func = is_scalar_func;

/* T-SQL doesn't allow call procedure in function */
/* T-SQL doesn't allow procedure calls in a function */
if (estate->func && estate->func->fn_oid != InvalidOid && estate->func->fn_prokind == PROKIND_FUNCTION && estate->func->fn_is_trigger == PLTSQL_NOT_TRIGGER /* check EXEC is running
* in the body of
* function */
Expand Down Expand Up @@ -1823,6 +1823,14 @@ exec_stmt_exec_sp(PLtsql_execstate *estate, PLtsql_stmt_exec_sp *stmt)
char *querystr;
int ret = 0;

/* T-SQL doesn't allow procedure calls in a function */
if (estate->func && estate->func->fn_oid != InvalidOid && estate->func->fn_prokind == PROKIND_FUNCTION && estate->func->fn_is_trigger == PLTSQL_NOT_TRIGGER)
{
ereport(ERROR,
(errcode(ERRCODE_INVALID_FUNCTION_DEFINITION),
errmsg("Only functions can be executed within a function")));
}

switch (stmt->sp_type_code)
{
case PLTSQL_EXEC_SP_CURSOR:
Expand Down
42 changes: 42 additions & 0 deletions test/JDBC/expected/exec_sp_in_udf-vu-cleanup.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
use master
go
drop table t1_exec_sp_in_udf
go
drop table t2_exec_sp_in_udf
go
drop procedure sp_myproc
go
drop procedure p1_exec_sp_in_udf
go
drop function f1_exec_sp_in_udf
go
drop function f2_exec_sp_in_udf
go
drop function f3_exec_sp_in_udf
go
drop function f4_exec_sp_in_udf
go
drop function f5_exec_sp_in_udf
go
drop function f6_exec_sp_in_udf
go
drop function f6a_exec_sp_in_udf
go
drop function f7_exec_sp_in_udf
go
drop function f8_exec_sp_in_udf
go
drop function f9_exec_sp_in_udf
go
drop function f_scalar_exec_sp_in_udf
go
drop function f_tvf_exec_sp_in_udf
go
drop function f_itvf_exec_sp_in_udf
go
use tempdb
go
drop procedure p_tempdb_exec_sp_in_udf
go
use master
go
32 changes: 32 additions & 0 deletions test/JDBC/expected/exec_sp_in_udf-vu-prepare.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
use master
go
create table t1_exec_sp_in_udf (a int)
go
create procedure sp_myproc as return 0
go
create function f_scalar_exec_sp_in_udf(@p int)
returns int as
begin
return @p
end
go

create function f_tvf_exec_sp_in_udf()
returns @tv table (a int)
begin
insert @tv values(123)
return
end
go

create function f_itvf_exec_sp_in_udf()
returns table
return (select 123 as a)
go

use tempdb
go
create procedure p_tempdb_exec_sp_in_udf as return 0
go
use master
go
284 changes: 284 additions & 0 deletions test/JDBC/expected/exec_sp_in_udf-vu-verify.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,284 @@
use master
go

create function f1_exec_sp_in_udf()
returns int as
begin
exec sp_executesql 'select 123'
return 0
end
go
select dbo.f1_exec_sp_in_udf()
go
~~START~~
int
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~

declare @v int = dbo.f1_exec_sp_in_udf()
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~

declare @v int
select @v = dbo.f1_exec_sp_in_udf()
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~

declare @v int
set @v = dbo.f1_exec_sp_in_udf()
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~

select * from t1_exec_sp_in_udf where a = dbo.f1_exec_sp_in_udf()
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~

insert t1_exec_sp_in_udf values(dbo.f1_exec_sp_in_udf())
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~

delete t1_exec_sp_in_udf where a = dbo.f1_exec_sp_in_udf()
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~

declare @v int
set @v = (select dbo.f1_exec_sp_in_udf())
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~

select sqrt(dbo.f1_exec_sp_in_udf())
go
~~START~~
float
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~

create table t2_exec_sp_in_udf(a int, b int default dbo.f1_exec_sp_in_udf())
go
insert t2_exec_sp_in_udf(a) values(1)
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~


create function f2_exec_sp_in_udf()
returns int as
begin
exec dbo.sp_helpdb
return 0
end
go
select dbo.f2_exec_sp_in_udf()
go
~~START~~
int
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~


create function f3_exec_sp_in_udf()
returns int as
begin
exec [sp_helpdb]
return 0
end
go
select dbo.f3_exec_sp_in_udf()
go
~~START~~
int
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~


create function f4_exec_sp_in_udf()
returns @tv table(a int) as
begin
exec sp_myproc
return
end
go
select * from dbo.f4_exec_sp_in_udf()
go
~~START~~
int
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~


create function f5_exec_sp_in_udf()
returns @tv table(a int) as
begin
exec dbo.[sp_myproc]
return
end
go
select * from dbo.f5_exec_sp_in_udf()
go
~~START~~
int
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~


create function f6_exec_sp_in_udf()
returns @tv table(a int) as
begin
exec tempdb..p_tempdb_exec_sp_in_udf
return
end
go
select * from dbo.f6_exec_sp_in_udf()
go
~~START~~
int
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~


-- do not allow calling with EXEC
create function f6a_exec_sp_in_udf(@p int)
returns int as
begin
declare @v int
exec @v = f1_exec_sp_in_udf
return @v
end
go
select dbo.f6a_exec_sp_in_udf(123)
go
~~START~~
int
~~ERROR (Code: 33557097)~~

~~ERROR (Message: Only functions can be executed within a function)~~


-- multi-statement TVF cannot be called with EXEC
exec dbo.f_tvf_exec_sp_in_udf
go
~~ERROR (Code: 33557097)~~

~~ERROR (Message: master_dbo.f_tvf_exec_sp_in_udf() is not a procedure)~~

create function f7_exec_sp_in_udf()
returns int
begin
exec dbo.f_tvf_exec_sp_in_udf
return
end
go
select * from dbo.f7_exec_sp_in_udf()
go
~~START~~
int
~~ERROR (Code: 33557097)~~

~~ERROR (Message: master_dbo.f_tvf_exec_sp_in_udf() is not a procedure)~~


-- inline TVF should not be callable with EXEC, but Babelfish currently allows this
-- when this gets fixed so that an error is raised, the result of this test will change
exec dbo.f_itvf_exec_sp_in_udf
go
create function f8_exec_sp_in_udf()
returns int
begin
exec dbo.f_itvf_exec_sp_in_udf
return
end
go
select * from dbo.f8_exec_sp_in_udf()
go
~~START~~
int
<NULL>
~~END~~



-- procedure and trigger are not affected:
create trigger tr1 on t1_exec_sp_in_udf for insert as
begin
exec sp_executesql 'select 123 as in_trigger'
end
go
insert t1_exec_sp_in_udf values(456)
go
~~START~~
int
123
~~END~~

~~ROW COUNT: 1~~

select * from t1_exec_sp_in_udf
go
~~START~~
int
456
~~END~~


create procedure p1_exec_sp_in_udf
as
begin
exec sp_executesql 'select 123 as in_procedure'
end
go
exec p1_exec_sp_in_udf
go
~~START~~
int
123
~~END~~


-- scalar UDF can still be called with EXEC
declare @v int
exec @v = f_scalar_exec_sp_in_udf 123
select @v as f_scalar_exec_sp_in_udf
go
~~START~~
int
123
~~END~~


create function f9_exec_sp_in_udf(@p int)
returns int as
begin
declare @v int
exec @v = f_scalar_exec_sp_in_udf @p
return @v
end
go
select dbo.f9_exec_sp_in_udf(123)
go
~~START~~
int
123
~~END~~

Loading

0 comments on commit 5c3ff29

Please sign in to comment.