Function Syntax Error

VS29 246 Reputation points
2022-08-20T11:41:27.503+00:00

Hi ,

I am trying to create a function and it is throwing the syntax error...unable to spot what the error is...can someone please shed some light..

--Query #1  
IF OBJECT_ID('dbo.fn_Interval', 'IF') IS NOT NULL  
	DROP FUNCTION dbo.fn_Interval;  
GO  
CREATE FUNCTION dbo.fn_Interval(  
									 @XYZ VARCHAR(32)  
								    ,@startDate DATE  
									,@endDate DATE  
									,@Count INT  
									,@outputType INT  
									)  
RETURNS TABLE  
AS RETURN (  
  
	IF @outputType = 1 GOTO output_One  
	IF @outputType = 2 GOTO output_Two  
	ELSE GOTO output_Three  
  
	output_One:  
			  
			SELECT GETDATE() "Todays", DATEADD(DAY, 1, GETDATE()) "Tomorrow"  
		  
	output_Two:  
		  
			SELECT GETDATE() "Today";  
  
	output_Three:  
  
			SELECT GETDATE() "Todays", DATEADD(DAY, -1, GETDATE()) "Yesterday"  
);  
GO  
  
--Query 1 returns the below error  
/*  
Msg 103010, Level 16, State 1, Line 134  
Parse error at line: 9, column: 11: Incorrect syntax near '('.  
*/  
  
--Query #2  
  
IF OBJECT_ID('dbo.fn_Interval', 'IF') IS NOT NULL  
	DROP FUNCTION dbo.fn_Interval;  
GO  
CREATE FUNCTION dbo.fn_Interval(  
									 @XYZ VARCHAR(32)  
								    ,@startDate DATE  
									,@endDate DATE  
									,@Count INT  
									,@outputType INT  
									)  
RETURNS TABLE  
AS RETURN (  
  
			SELECT GETDATE() "Todays", DATEADD(DAY, 1, GETDATE()) "Tomorrow"  
		  
);  
GO  
--Query 2 runs successfully  

trying to understand where the mistake is..

Env - Dedicated SQL Pool.

Thank you!

Azure SQL Database
Developer technologies | Transact-SQL
SQL Server | Other
0 comments No comments
{count} votes

Accepted answer
  1. Viorel 122.6K Reputation points
    2022-08-20T12:08:56.247+00:00

    It seems that an Inline Table-Valued Function cannot include multiple statements.

    Check if these variants work in your environment:

    -- Inline Table-Valued Function  
      
    CREATE FUNCTION dbo.fn_Interval (  
        @XYZ VARCHAR(32),  
        @startDate DATE,  
        @endDate DATE,  
        @Count INT,  
        @outputType INT  
    )  
    RETURNS TABLE  
    AS RETURN (  
        SELECT GETDATE() "Today", DATEADD(DAY, 1, GETDATE()) "Tomorrow"  
        where @outputType = 1  
        union all  
        SELECT GETDATE(), null  
        where @outputType = 2  
        union all  
        SELECT GETDATE(), DATEADD(DAY, -1, GETDATE())   
        where @outputType not in (1,2)  
    )  
    

    You can also use CASE or IIF inside a single SELECT.

    Or:

    -- Multi-Statement Table-Valued Function  
      
    CREATE FUNCTION dbo.fn_Interval (  
        @XYZ VARCHAR(32),  
        @startDate DATE,  
        @endDate DATE,  
        @Count INT,  
        @outputType INT  
    )  
    RETURNS @t TABLE (Today date, Tomorrow date)  
    begin  
        IF @outputType = 1   
            insert @t   
            select GETDATE(), DATEADD(DAY, 1, GETDATE())  
        else if @outputType = 2  
            insert @t   
            SELECT GETDATE(), null  
        else  
            insert @t   
            SELECT GETDATE(), DATEADD(DAY, -1, GETDATE())  
      
        return   
    end  
    

    If you want to return a different set of columns depending on parameters, then consider procedures instead of functions.

    1 person found this answer helpful.
    0 comments No comments

2 additional answers

Sort by: Most helpful
  1. Ronen Ariely 15,206 Reputation points
    2022-08-20T12:22:27.947+00:00

    Hi,

    In the first query you are using multiple statements in the return section which lead to the error.

    There are two types of table functions

    (1) Inline Table-Valued Function, which can use only one statement since it is parsed as inline with the query that call it.

    (2) Multi-Statement Table-Valued Function

    Your syntax is the one that fits Inline Table-Valued Function but you use multiple Statements in the first one

    Ops... I see that @Viorel already published his answer before me, so you can mark his answer :-)

    I will just add a link to the official documentation where you can get more info and examples:

    https://learn.microsoft.com/en-us/sql/t-sql/statements/create-function-transact-sql?view=sql-server-ver16&WT.mc_id=DP-MVP-5001699

    1 person found this answer helpful.
    0 comments No comments

  2. VS29 246 Reputation points
    2022-08-20T18:47:11.383+00:00

    You guys are amazing...Thanks again @Ronen Ariely and @Viorel !!


Your answer

Answers can be marked as Accepted Answers by the question author, which helps users to know the answer solved the author's problem.