Function return values

  • I have a function that returns a table of values and i like a way to list those values in a query so can see if a field exists

    returns @WorkList Table
    (
            rowid                Int identity,
            SiteDetailID        UNIQUEIDENTIFIER,
            JobNumber            Varchar(20),
            JobName                Varchar(100)
    )

    as a list of names and types

    Thanks

  • What is your question exactly?

    Thom~

    Excuse my typos and sometimes awful grammar. My fingers work faster than my brain does.
    Larnu.uk

  • in a function I can return a table variable or datatype as shown above if I do the same in a stored procedure I can use sys.dm_exec_describe_first_result_set to tell me what the table structure is that will be returned can I run the same thing for a function to see the output i.e.

    rowid Int identity,
    SiteDetailID UNIQUEIDENTIFIER,
    JobNumber Varchar(20),
    JobName Varchar(100)

    as a list that I can check for a column name

    thanks

    Matt

  • Maybe you could query
    INFORMATION_SCHEMA.ROUTINE_COLUMNS?

    If you haven't even tried to resolve your issue, please don't expect the hard-working volunteers here to waste their time providing links to answers which you could easily have found yourself.

  • Interesting q.  I don't believe that info is stored in any system table, I think SQL generates it (only) when the function executes.

    To get the column names, you could use "TOP (0)" to get them without actually executing the query, for example:

    SELECT TOP (0) * INTO #col_names FROM dbo.DelimitedSplit8K('a,b,c',',');

    Then check for the column name(s) in #col_names:


    IF EXISTS(SELECT 1 FROM tempdb.sys.columns WHERE object_id = OBJECT_ID('tempdb.dbo.#col_names') AND name = 'Item')
        PRINT 'Column exists.'
    ELSE
        PRINT 'Column doesn''t exist.'

    SQL DBA,SQL Server MVP(07, 08, 09) "Money can't buy you happiness." Maybe so, but it can make your unhappiness a LOT more comfortable!

  • Phil's suggestion works for table valued functions, and you can also use dm_exec_describe_first_result_set but you'd have to make the first parameter as a query to the TVF not just the name, so something like these work for me:

    SELECT * FROM INFORMATION_SCHEMA.ROUTINE_COLUMNS WHERE TABLE_NAME = 'fun_GetEventCurrent'
    --or
    SELECT * FROM sys.dm_exec_describe_first_result_set(N'SELECT * FROM dbo.fun_GetEventCurrent(120404)', NULL, 0)

  • The column definitions of the returned tables from multi-line and in-line table valued functions are stored in sys.columns.  Run the following and see what you get:


    select *
    from
    sys.sql_modules sm
    inner join sys.columns col
      on sm.object_id = col.object_id
    ;

  • Perhaps this will provide what you are looking for 
    sys.dm_exec_describe_first_result_set_for_object

  • Again, try this:


    select
    object_name(sm.object_id) ObjectName
    , col.name ColumnName
    ,ca1.DataType
    from
    sys.sql_modules sm
    inner join sys.columns col
      on sm.object_id = col.object_id
    inner join sys.types typ
      on col.system_type_id = typ.system_type_id
       and col.user_type_id = typ.user_type_id
    cross apply (select
      typ.name + case when typ.name in ('nchar','char','binary') then '(' + cast(col.max_length as varchar) + ')'
           when typ.name in ('nvarchar','varchar','varbinary') then
             case when col.max_length = -1 then '(max)'
                       else case when typ.name in ('varchar','varbinary') then '(' + cast(col.max_length as varchar) + ')'
                                        else '(' + cast(col.max_length/2 as varchar) + ')'
                         end
             end
           when typ.name in ('numeric','decimal') then '(' + cast(col.precision as varchar) + ',' + cast(col.scale as varchar) + ')'
           when typ.name in ('float','real') then '(' + cast(col.precision as varchar) + ')'
           when typ.name in ('datetime2','datetimeoffset','time') then '(' + cast(col.scale as varchar) + ')'
           else ''
          end as DataType) ca1

    ;

  • All,

    Thanks so much, I have taken a bit of all the answer to get all I need, i'm shamed to say when I have seen the response it was a "Doh" moment.

    Again tank you

    Matt

  • Lynn,
    There is a little mistake in how your code calculates the length for nchar.
    This should be right:
    typ.name + case
            when typ.name like '%char' or typ.name like '%binary' then
             case when col.max_length = -1 then '(max)'
                    else '(' + cast(
                            col.max_length/ case when typ.name like 'n%' then 2 else 1 end
                            as varchar)
                        + ')'
       end

    _____________
    Code for TallyGenerator

  • Sergiy - Wednesday, May 3, 2017 7:47 PM

    Lynn,
    There is a little mistake in how your code calculates the length for nchar.
    This should be right:
    typ.name + case
            when typ.name like '%char' or typ.name like '%binary' then
             case when col.max_length = -1 then '(max)'
                    else '(' + cast(
                            col.max_length/ case when typ.name like 'n%' then 2 else 1 end
                            as varchar)
                        + ')'
       end

    Missed that, thanks.

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

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