July 3, 2012 at 10:37 am
declare @SQLString varchar(max)
set @SQLString='EXEC dbo.mysproc ''ABC'''
insert INTO #TEMP_table
exec (@SQLString)
table has to be created on the fly. Any thoughts please?
July 3, 2012 at 10:43 am
Why does the table have to be created on the fly? You know the output of the proc already, so create the temp table using that basis.
If you say you want one routine for all procs, you're being lazy. Create routines for each proc that needs this.
July 3, 2012 at 10:45 am
to capture the results form a stored procedure, the table must exist, with all the columns defined;
then you can do something like this:
IF NOT EXISTS (SELECT * FROM sysobjects WHERE id = OBJECT_ID(N'WHO_DATA') AND xtype in (N'U'))
CREATE TABLE WHO_DATA (
[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,
[REQUESTID] INT NULL
)
--table exists, insert some data
INSERT INTO WHO_DATA(SPID,Status,Login,HostName,BlkBy,DBName,Command,CPUTime,DiskIO,LastBatch,ProgramName,SPIDINT,REQUESTID)
EXEC sp_who2
there's a bit of a work around you can try by using openrowset:, it tends to be a LOT slower, but it works:
--database name required
SELECT *
INTO #tmp
FROM OPENROWSET( 'SQLNCLI',
'Server=(local);Trusted_Connection=yes;',
'SET FMTONLY OFF; SET NOCOUNT ON; exec master.sys.sp_who'
)
Lowell
July 3, 2012 at 10:47 am
Steve Jones - SSC Editor (7/3/2012)
Why does the table have to be created on the fly? You know the output of the proc already, so create the temp table using that basis.If you say you want one routine for all procs, you're being lazy. Create routines for each proc that needs this.
Thanks. I am not a developer. I am just trying to come up a solution based on the requirement. I am sure we should go and optimize our queries. This is for a report. You have a sproc to generate report, if you have to query the output of the sproc how would you do that? I would still like to know if the method which i stated is possible or not.
July 3, 2012 at 11:14 am
sqldba_newbie (7/3/2012)
Steve Jones - SSC Editor (7/3/2012)
Why does the table have to be created on the fly? You know the output of the proc already, so create the temp table using that basis.If you say you want one routine for all procs, you're being lazy. Create routines for each proc that needs this.
Thanks. I am not a developer. I am just trying to come up a solution based on the requirement. I am sure we should go and optimize our queries. This is for a report. You have a sproc to generate report, if you have to query the output of the sproc how would you do that? I would still like to know if the method which i stated is possible or not.
This whole thing just sounds like a monster kludge in the making. I see no reason for the dynamic sql at all and creating a generic proc to return data into an "on the fly" type of temp table so you can query it sounds like the process needs a lot of help. Why does a report need to take the results of a proc and then only get some of the rows? Why not change the original proc to return the data that you need?
To directly answer your question, no you can't do this like you presented.
_______________________________________________________________
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/
July 3, 2012 at 11:15 am
I don't think it's possible. Usually a sproc has a known result set, even for a report, so you would have the values being returned.
July 3, 2012 at 12:07 pm
Lowell (7/3/2012)
there's a bit of a work around you can try by using openrowset:, it tends to be a LOT slower, but it works:
--database name required
SELECT *
INTO #tmp
FROM OPENROWSET( 'SQLNCLI',
'Server=(local);Trusted_Connection=yes;',
'SET FMTONLY OFF; SET NOCOUNT ON; exec master.sys.sp_who'
)
It should be noted that using this technique requires us to enable Ad Hoc Distributed Queries. The option is disabled by default.
-- view your settings
EXEC sys.sp_configure
@configname = 'Ad Hoc Distributed Queries';
Please see the Security Note in BOL:
Ad Hoc Distributed Queries Option (SQL Server 2005)
There are no special teachers of virtue, because virtue is taught by the whole community.
--Plato
July 3, 2012 at 1:06 pm
opc.three (7/3/2012)
Lowell (7/3/2012)
there's a bit of a work around you can try by using openrowset:, it tends to be a LOT slower, but it works:
--database name required
SELECT *
INTO #tmp
FROM OPENROWSET( 'SQLNCLI',
'Server=(local);Trusted_Connection=yes;',
'SET FMTONLY OFF; SET NOCOUNT ON; exec master.sys.sp_who'
)
this worked. thanks
It should be noted that using this technique requires us to enable Ad Hoc Distributed Queries. The option is disabled by default.
-- view your settings
EXEC sys.sp_configure
@configname = 'Ad Hoc Distributed Queries';
Please see the Security Note in BOL:
Viewing 8 posts - 1 through 7 (of 7 total)
You must be logged in to reply to this topic. Login to reply