Using stored proc in a user defined function.

  • Hi All,

    Can I use a system\user stored procedure in a sql function.

    For ex:

    I want to get the sp_who result set through a user defined fucntion Or inserting sp_who's result set in a new table somthing like using below query.

    select * into t2 from (exec sp_who)

    Thanks,

    DR.

  • no, sorry DR; a function cannot call a stored procedure, only extended stored procedures;

    the reason is a function is not allowed to affect objects, and since a stored procedure could (potentially) do things like CREATE/ALTER/dynamic SQL, it's not allowed.

    you could stick the results of sp_who into a temp or permenant table just prior to calling the function, and the function wold have no problem gathering info from a table or temp table;

    here's a simple example of that:

    CREATE PROCEDURE PR_CAPTURESP_WHO

    AS

    BEGIN

    SET NOCOUNT ON

    IF NOT EXISTS (SELECT * FROM sysobjects WHERE id = OBJECT_ID(N'WHORESULTS') AND xtype in (N'U'))

    CREATE TABLE WHORESULTS (

    [WHORESULTSID] INT IDENTITY(1,1) NOT NULL PRIMARY KEY,

    [SPID] CHAR (5) NULL,

    [INSERTDT] DATETIME NULL DEFAULT(GETDATE()),

    [STATUS] VARCHAR(30) NULL,

    [LOGIN] VARCHAR(30) NULL,

    [HOSTNAME] VARCHAR(30) NULL,

    [BLKBY] VARCHAR(30) NULL,

    [DBNAME] VARCHAR(30) NULL,

    [COMMAND] VARCHAR(30) NULL,

    [CPUTIME] INT NULL,

    [DISKIO] INT NULL,

    [LASTBATCH] VARCHAR(30) NULL,

    [PROGRAMNAME] VARCHAR(200) NULL,

    [SPIDINT] INT NULL

    )

    --table exists, insert some data

    INSERT INTO WHORESULTS(SPID,Status,Login,HostName,BlkBy,DBName,Command,CPUTime,DiskIO,LastBatch,ProgramName,SPIDINT)

    EXEC sp_who2

    --don't care about spids less than 50 anyway:

    DELETE FROM WHORESULTS WHERE SPIDINT < 50

    here's a quick list i saved of Function limitations:

    ··UDF has No Access to Structural and Permanent Tables.

    ··UDF can call Extended Stored Procedure, which can have access to structural and permanent tables. (No Access to Stored Procedure)

    ··UDF Accepts Lesser Numbers of Input Parameters.

    ··UDF can have upto 1023 input parameters, Stored Procedure can have upto 2100 input parameters.

    ··UDF Prohibit Usage of Non-Deterministic Built-in Functions Functions GETDATE() etc can not be used UDFs, but can be used in Stored Procedure

    ··UDF Returns Only One Result Set or Output Parameter Due to this it can be used in SELECT statement but can not return multiple result set like Stored Procedure

    ··UDF can not Call Stored Procedure Only access to Extended Stored Procedure.

    ··UDF can not Execute Dynamic SQL or Temporary Tables

    ··UDF can not run dynamic SQL which are dynamically build in UDF. Temporary Tables can not be used in UDF as well.

    ··UDF can not Return XML FOR XML is not allowed in UDF

    ··UDF does not support SET options SET options which can change Server level or transaction level settings are prohibited in UDFs. (SET ROWCOUNT etc)

    ··UDF does not Support Error Handling RAISEERROR or @@ERROR are not allowed in UDFs.

    ··UDF does not Support print statements for debugging

    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!

Viewing 2 posts - 1 through 1 (of 1 total)

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