Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Copy rows returned from a RESTORE FILELISTONLY command into a tble Expand / Collapse
Author
Message
Posted Thursday, June 10, 2010 11:55 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, December 16, 2010 10:48 AM
Points: 22, 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?


Post #935609
Posted Monday, June 21, 2010 4:32 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Tuesday, June 17, 2014 9:54 AM
Points: 164, Visits: 954
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

Post #940683
Posted Tuesday, June 22, 2010 5:09 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Tuesday, May 10, 2011 2:08 PM
Points: 405, Visits: 2,670
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
Post #940926
Posted Tuesday, June 22, 2010 6:09 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, December 16, 2010 10:48 AM
Points: 22, Visits: 51
That works just great... Thank you for your input. it is much appreciated.
Post #940967
Posted Tuesday, June 22, 2010 7:25 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, December 16, 2010 10:48 AM
Points: 22, 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???
Post #941025
Posted Tuesday, June 22, 2010 9:04 AM
SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Tuesday, May 10, 2011 2:08 PM
Points: 405, Visits: 2,670
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
Post #941120
Posted Tuesday, June 22, 2010 9:34 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Thursday, December 16, 2010 10:48 AM
Points: 22, Visits: 51
Perfect !!! Thanks so much. I am still learning all the ins and outs of SQL. You help is deeply appreciated.
Post #941149
Posted Tuesday, August 28, 2012 1:29 PM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Saturday, July 19, 2014 7:52 PM
Points: 43, Visits: 69
I realize this post is old... but it helped me solved my issue with capturing RESTORE HEADERONLY data into a temp table.

Cheers! :)
Post #1351215
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse