table variable in a table-valued function

  • The code that is building the table variable works great outside of the code creating the function. Once I add it the the function, it would not parse.

    Am I dealing with a syntax issue here? I know that I can not use a temp table in this function, which is the reason why I am going with a table variable (@T_stage).

    Thanks a lot.

    CREATE function new_function

    (

    @some_param nvarchar(20)='MISSED')

    RETURNS TABLE

    AS

    RETURN

    (BEGIN

    declare @T_stage TABLE (field1 VARCHAR(40) NOT NULL,

    field2 NVARCHAR (10) NOT NULL PRIMARY KEY,

    field3 DATETIME NULL)

    INSERT @T_COMPANY_PAYROLL_LAST

    select MAX (LEGAL_NM) AS LEGAL_NAME,

    MAX (TCPRL.VEND_CO_ID) AS VEND_CO_ID,

    MAX(tcx.max_process_date) as LTST_PROCESSED_CHK_DATE

    --INTO #T_COMPANY_PAYROLL_LAST

    FROM t_bps_company_extract TCX

    INNER JOIN

    T_COMPANY_PAYROLL TCPRL

    ON TCPRL.Vend_CO_ID=TCX.VEND_CO_ID_TEXT

    WHERE TCX.Company_status = 'Active'

    group by TCPRL.vend_co_id, TCX.LEGAL_NM

    END

    )

  • You don't need the table declaration section. The function itself is a table variable. Your function needs only to have the SELECT statement in it.

    CREATE function new_function (@some_param nvarchar(20)='MISSED')

    RETURNS TABLE

    AS

    RETURN(

    select MAX (LEGAL_NM) AS LEGAL_NAME,

    MAX (TCPRL.VEND_CO_ID) AS VEND_CO_ID,

    MAX(tcx.max_process_date) as LTST_PROCESSED_CHK_DATE

    FROM t_bps_company_extract TCX

    INNER JOIN T_COMPANY_PAYROLL TCPRL

    ON TCPRL.Vend_CO_ID=TCX.VEND_CO_ID_TEXT

    WHERE TCX.Company_status = 'Active'

    group by TCPRL.vend_co_id, TCX.LEGAL_NM

    )

    GO

    John Rowan

    ======================================================
    ======================================================
    Forum Etiquette: How to post data/code on a forum to get the best help[/url] - by Jeff Moden

  • John,

    I appreciate your prompt reply. The reason why I am using the table declaration is that I have more code that follows the first part. I intend to join to the records in the table variable for speed reasons. Think of it almost like joining to a view in a table-valued function. If I did not have any more codes after the first set of codes, then your suggestion would be the way to go.

    Thanks again.

    Messan

  • In that case, you'll want to go with a multi-statement table valued function. Check in BOL for details, but here's a quick example.

    CREATE FUNCTION dbo.udf_functest(@ID int)

    RETURNS @ReturnTable TABLE (TranID int, Amount money)

    AS

    BEGIN

    DECLARE @tempTable TABLE (ID int, TranID int, Amount money)

    INSERT INTO @tempTable

    SELECT ID,

    TransactionID,

    Amount

    FROM dbo.Table1

    WHERE ID = @ID

    INSERT INTO @ReturnTable

    SELECT TranID,

    Amount

    FROM dbo.Table2 t1

    INNER JOIN @tempTable t2 ON t1.ID = t2.ID

    RETURN

    END

    GO

    John Rowan

    ======================================================
    ======================================================
    Forum Etiquette: How to post data/code on a forum to get the best help[/url] - by Jeff Moden

  • Thank you for pointing me in the right direction.

    Messan

  • Just be aware that multi-statement table valued functions tend to perform less then admirably, especially if they'll be returning lots of rows.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • In this case,

    when i call new_function(), i should get value for @some_param to "missed" which you have initialized.

    But i am getting "An insufficient number of arguments were supplied for the procedure or function" error.

    how should i do?

  • calling object if it has a temp table or another table variable must have the same exact structure to your table valued function that you are calling. also make sure the ordinal position and datatype , size all matches.

  • function parameters are not optional the way stored procedures are. All values must be passed, or the default placehodler must be used in it's place

    you have to use the default keyword if you wnat to skip the value:

    not allowed:

    SELECT * FROM new_function ()

    the way the default value must be called instead:

    SELECT * FROM new_function (default)

    SELECT * FROM new_function ('MISSED')

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • Please note: 6 year old thread.

    Gail Shaw
    Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
    SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

    We walk in the dark places no others will enter
    We stand on the bridge and no one may pass
  • Joe this thread is 6+ years old and the OP hasn't even logged in for more than 2 years. However your analogy on using the scratch tape and rewinding nearly made me spit out my drink. That was funny. 😀

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

Viewing 11 posts - 1 through 10 (of 10 total)

You must be logged in to reply to this topic. Login to reply