Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

insert output to temp table Expand / Collapse
Author
Message
Posted Tuesday, July 3, 2012 10:37 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Wednesday, September 14, 2016 12:36 PM
Points: 1,516, Visits: 3,556
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?
Post #1324499
Posted Tuesday, July 3, 2012 10:43 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: Administrators
Last Login: 2 days ago @ 1:17 PM
Points: 34,146, Visits: 18,305
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.







Follow me on Twitter: @way0utwest

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1324509
Posted Tuesday, July 3, 2012 10:45 AM


SSChampion

SSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampionSSChampion

Group: General Forum Members
Last Login: Thursday, September 22, 2016 4:54 AM
Points: 14,468, Visits: 38,065
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

--
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!
Post #1324513
Posted Tuesday, July 3, 2012 10:47 AM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Wednesday, September 14, 2016 12:36 PM
Points: 1,516, Visits: 3,556
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.
Post #1324516
Posted Tuesday, July 3, 2012 11:14 AM


SSCoach

SSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoachSSCoach

Group: General Forum Members
Last Login: 2 days ago @ 2:51 PM
Points: 15,981, Visits: 16,517
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 Moden's splitter.

Cross Tabs and Pivots, Part 1 – Converting Rows to Columns
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs
Understanding and Using APPLY (Part 1)
Understanding and Using APPLY (Part 2)
Post #1324545
Posted Tuesday, July 3, 2012 11:15 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: Administrators
Last Login: 2 days ago @ 1:17 PM
Points: 34,146, Visits: 18,305
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.







Follow me on Twitter: @way0utwest

Forum Etiquette: How to post data/code on a forum to get the best help
Post #1324549
Posted Tuesday, July 3, 2012 12:07 PM


SSCertifiable

SSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiableSSCertifiable

Group: General Forum Members
Last Login: Wednesday, September 21, 2016 3:34 AM
Points: 7,932, Visits: 14,333
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
Post #1324591
Posted Tuesday, July 3, 2012 1:06 PM
SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: Wednesday, September 14, 2016 12:36 PM
Points: 1,516, Visits: 3,556
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:

Ad Hoc Distributed Queries Option (SQL Server 2005)
Post #1324628
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse