Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Copy rows returned from a RESTORE FILELISTONLY command into a tble


Copy rows returned from a RESTORE FILELISTONLY command into a tble

Author
Message
bryan.duchesne
bryan.duchesne
SSC Rookie
SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)

Group: General Forum Members
Points: 42 Visits: 51
I am trying to copy the rows returned from a RESTORE FILELISTONLY command into a temp table so that I can get the current column structure so I can then query the results to further filter them.

sp_configure 'Ad Hoc Distributed Queries', 1
GO
RECONFIGURE
GO



SELECT a.* into #tmp FROM OPENROWSET('SQLNCLI','Server=(local)\SQLEXPRESS;Trusted_Connection=yes;','RESTORE FILELISTONLY FROM DISK =''c:\code3Billing\ClientSQLData\Master\code3billing.bak''') as a

but I am getting an error


Msg 7357, Level 16, State 2, Line 4
Cannot process the object "RESTORE FILELISTONLY FROM DISK ='c:\code3Billing\ClientSQLData\Master\code3billing.bak'". The OLE DB provider "SQLNCLI" for linked server "(null)" indicates that either the object has no columns or the current user does not have permissions on that object.

I have permissions since I can run the RESTORE command as a stand-alone. I am sure there are columns since I can see them when I do run the command as stand-alone.

Does anyone have any insight here?
Jesse Reich
Jesse Reich
SSC-Enthusiastic
SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)SSC-Enthusiastic (194 reputation)

Group: General Forum Members
Points: 194 Visits: 1019
Hi,

Not sure if this will help, but you should be able to achieve the same thing this way...


CREATE PROCEDURE usp_TestRestore AS
BEGIN
RESTORE FILELISTONLY FROM DISK = 'c:\code3Billing\ClientSQLData\Master\code3billing.bak'
END
GO

IF OBJECT_ID('tempdb..#Restore') IS NOT NULL DROP TABLE #Restore

CREATE TABLE #Restore (
LogicalName NVARCHAR(128),
PhysicalName NVARCHAR(260),
[Type] CHAR(1),
FileGroupName NVARCHAR(128),
Size NUMERIC(20,0),
MaxSize NUMERIC(20,0),
FileID BIGINT,
CreateLSN NUMERIC(25,0),
DropLSN NUMERIC(25,0),
UniqueID UNIQUEIDENTIFIER,
ReadOnlyLSN NUMERIC(25,0),
ReadWriteLSN NUMERIC(25,0),
BackupSizeInBytes BIGINT,
SourceBlockSize INT,
FileGroupID INT,
LogGroupGUID UNIQUEIDENTIFIER,
DifferentialBaseLSN NUMERIC(25,0),
DifferentialBaseGUID UNIQUEIDENTIFIER,
IsReadOnly BIT,
IsPresent BIT,
TDEThumbprint VARBINARY(32)
)

INSERT #Restore
EXEC usp_TestRestore

SELECT * FROM #Restore


steve-893342
steve-893342
SSC-Addicted
SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)

Group: General Forum Members
Points: 447 Visits: 2670
If you embed your RESTORE FILELISTONLY in an EXEC statement, you can still use your OPENROWSET approach

SELECT a.* INTO #tmp FROM OPENROWSET('SQLNCLI','Server=(local)\SQLEXPRESS;Trusted_Connection=yes',
'EXEC(''SET FMTONLY OFF RESTORE FILELISTONLY FROM DISK=''''C:\code3Billing\ClientSQLData\Master\code3billing.bak'''''')') AS a
bryan.duchesne
bryan.duchesne
SSC Rookie
SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)

Group: General Forum Members
Points: 42 Visits: 51
That works just great... Thank you for your input. it is much appreciated.
bryan.duchesne
bryan.duchesne
SSC Rookie
SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)

Group: General Forum Members
Points: 42 Visits: 51
I would also like to do a similar thing with the HEADERONLY but when I try to clone your code I get an error. Here is my code:

SELECT a.* INTO #hdr FROM OPENROWSET('SQLNCLI','Server=(local)\SQLEXPRESS;Trusted_Connection=yes',
'EXEC(''SET FMT OFF RESTORE HEADERONLY FROM DISK =''''c:\code3Billing\ClientSQLData\Master\code3billing.bak '''''')') AS a


Here is the error:

Cannot process the object "EXEC('SET FMT OFF RESTORE HEADERONLY FROM DISK =''c:\code3Billing\ClientSQLData\Master\code3billing.bak ''')". The OLE DB provider "SQLNCLI" for linked server "(null)" indicates that either the object has no columns or the current user does not have permissions on that object.


Am I missing something???
steve-893342
steve-893342
SSC-Addicted
SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)SSC-Addicted (447 reputation)

Group: General Forum Members
Points: 447 Visits: 2670
I think you're just missing the SET FMTONLY OFF setting

SELECT a.* INTO #hdr FROM OPENROWSET('SQLNCLI','Server=(local)\SQLEXPRESS;Trusted_Connection=yes',
'EXEC(''SET FMTONLY OFF RESTORE HEADERONLY FROM DISK =''''c:\code3Billing\ClientSQLData\Master\code3billing.bak '''''')') AS a
bryan.duchesne
bryan.duchesne
SSC Rookie
SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)SSC Rookie (42 reputation)

Group: General Forum Members
Points: 42 Visits: 51
Perfect !!! Thanks so much. I am still learning all the ins and outs of SQL. You help is deeply appreciated.
Patrick C. Joseph
Patrick C. Joseph
SSC Rookie
SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)SSC Rookie (47 reputation)

Group: General Forum Members
Points: 47 Visits: 143
I realize this post is old... but it helped me solved my issue with capturing RESTORE HEADERONLY data into a temp table.

Cheers! Smile
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search