Copy rows returned from a RESTORE FILELISTONLY command into a tble

  • 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?

  • 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

  • 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

  • That works just great... Thank you for your input. it is much appreciated.

  • 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???

  • 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

  • Perfect !!! Thanks so much. I am still learning all the ins and outs of SQL. You help is deeply appreciated.

  • I realize this post is old... but it helped me solved my issue with capturing RESTORE HEADERONLY data into a temp table.

    Cheers! 🙂

Viewing 8 posts - 1 through 7 (of 7 total)

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