I can't seem to find the right SQL for my program to COPY a database!

Robert Gustafson 606 Reputation points
2022-05-20T18:32:11+00:00

WHAT I HAVE:
Visual Basic 2019, .NET Framework 4+, WinForms, Entity Framework 6+, SQL Server (version unsure)

MY PROBLEM:
I want my program to be able to make a copy of a database--with a new catalog, data file, and log file--to a destination on the same machine (and same server), while keeping the original database--along its with catalog, data file, and log file--intact and unmoved.

VS Help advises using BACKUP and RESTORE, and my run-time code executes SQL to copy the following sample database with catalog name "contactlist2.mdf 12/8/2021 6:13:57 pm", data file name "C:\ProgramData\Robert AlanGustafson II\Social Contacts Tracker\1.0.0.0\contactlist2.mdf", and log file name "C:\ProgramData\Robert AlanGustafson II\Social Contacts Tracker\1.0.0.0\contactlist2_log.ldf" to a database with catalog name "contactlist3.mdf 12/8/2021 6:13:57 pm", data file name "C:\ProgramData\Robert AlanGustafson II\Social Contacts Tracker\1.0.0.0\contactlist3.mdf", and log file name "C:\ProgramData\Robert AlanGustafson II\Social Contacts Tracker\1.0.0.0\contactlist3_log.ldf"--basically, copying all "conctactlist2"'s to "contactlist3"'s--using the following procedure:

''' <summary>
''' copy one database to another
''' </summary>
''' <param name="SourceCatalogName">catalog name of source database</param>
''' <param name="SourceFileName">file name of source database</param>
''' <param name="DestinationCatalogName">catalog name of destination database</param>
''' <param name="DestinationFileName">file name of destination database</param>
''' <returns>True if successful, False if cancelled</returns>
''' <remarks>Note the following:<br></br>
''' 1. If either database is the same as the currently open one (if any), if the
'''    source database doesn't exist, or if an error occurs while making the copy,
'''    an exception is thrown<br></br>
''' 2. If a database with the given destination catalog name and/or a file with the
'''    same name as the desination primary file name already exists, then the
'''    CatlogExists and/or DatabaseFileExists events will be fired to allow the user to
'''    decide whether to cancel the operation or overwrite the catalog and/or file with
'''    the database copy</remarks>
Public Overridable Function Copy(ByVal SourceCatalogName As String, _
    ByVal SourceFileName As String, _
    ByVal DestinationCatalogName As String, ByVal DestinationFileName As String) As Boolean
    '   normalize names for and verify existence of source database
    CheckNamesForOpenExisting(SourceCatalogName, SourceFileName)
    '   normalize names for destination database
    CheckNamesForCreateNew(DestinationCatalogName, DestinationFileName)
    '   see if either database is already opened
    VerifyIsNotOpen(SourceCatalogName, SourceFileName)
    VerifyIsNotOpen(DestinationCatalogName, DestinationFileName)
    '   verify existence of source database
    Using Context As SocialContactsTracker1 = _
            GetContextForExistingDatabase(SourceCatalogName, SourceFileName)
        '   do nothing
    End Using
    '   see if we need to overwrite destination database
    Using Context As SocialContactsTracker1 = _
            GetContextForNewDatabase(DestinationCatalogName, DestinationFileName)
        If Context Is Nothing Then
            '   exit if destination database exists and is not to be overwritten
            Return False
        End If
    End Using
    '   copy database using backup and restore
    Using Context As SocialContactsTracker1 = GetPrototypeContext()
        Dim BackupFileName As String = _
            SourceFileName.Substring(0, SourceFileName.Length - 3) & "bak"
        Dim BackupDeviceName As String = _
            SourceCatalogName.Substring(0, SourceCatalogName.Length - 5) & "_TEMP"
        '   perform copy using backup and restore
        With Context.Database
            .ExecuteSqlCommand(Entity.TransactionalBehavior.DoNotEnsureTransaction, _
                "BACKUP DATABASE """ & SourceCatalogName _
                    & """ TO DISK='" & BackupFileName & "'; " _
                & "RESTORE FILELISTONLY FROM DISK='" &  BackupFileName & "'; " _
                & "RESTORE DATABASE """ & DestinationCatalogName _
                    & """ FROM DISK='" & BackupFileName _
                        & "' WITH MOVE '" & SourceCatalogName & "_Data' TO '" _
                        & DestinationFileName & "', " _
                    & "MOVE '" & SourceCatalogName & "_Log' TO '" _
                        & IO.Path.ChangeExtension(DestinationFileName, Nothing) & "_log.ldf'; ")
        End With
        If IO.File.Exists(BackupFileName) Then
            '   remove temporary backup file
            IO.File.Delete(BackupFileName)
        End If
    End Using
    '   flag operation successful
    Return True
End Function

My code throws the following exception:

Logical file 'contactlist2.mdf 12/8/2021 6:13:57 pm_Data' is not part of database 'contactlist3.mdf 5/22/2022 3:29:32 am'. Use RESTORE FILELISTONLY to list the logical file names.
RESTORE DATABASE is terminating abnormally.
Processed 352 pages for database 'contactlist2.mdf 12/8/2021 6:13:57 pm', file 'ContactList2.mdf' on file 9.
Processed 2 pages for database 'contactlist2.mdf 12/8/2021 6:13:57 pm', file 'ContactList2_log.ldf' on file 9.
BACKUP DATABASE successfully processed 354 pages in 0.431 seconds (6.416 MB/sec).

What is wrong with my syntax (since it's in my run-time code, I can't Intellisense-check it)?! How am I supposed to know the logical file names? I didn't formally define them in BACKUP! (Is there a way to specify them during BACKUP?) And somehow I don't think FILELISTONLY will help if I want to keep my VB.NET code simple.

Remember, I want everything copied, not merely moved!

As for the database catalog name, my program lets users create and open social-contact lists by specifying a name for a contact-list XML file--which contains the names of the catalog and .mdf database file that are subsequently created/opened by the program, both of which are derived from the contact-list name. (The user is allowed to create multiple contact lists, each with its own database. Don't ask why they might want to, but this makes copy functionality useful.) I need some system to give each database a unique catalog name. I use the .mdf file name plus the date and time the contact list is created to do this. When not trying to copy a database, this all works just fine in my program. As for the partial time stamp for the backup device, that's only because I derived its name from that of the backup file.

I sense that there's a problem with the syntax of the RESTORE DATABASE command. What is it?! Is there a way to "Intellisense" the generated SQL for syntax errors? I can't gleam from Help how to access the SQL editors and syntax-checkers.

Source code of procedure producing exception (There are references to other parts of the program omitted here; just focus on the SQL.):

PS. What's the best SQL for moving (not copying) a database to a new catalog, data file, and log file?

PPS. Remember, none of what I'm doing is across machines or across servers (although it could be in the future).

PPPS. I tried to add this new development to 1 of my previous posts on this issue, but the website won't do anything when I click "Submit." (I've had this problem before using the website after a lot of back-and-forth on a given issue!)

Windows Forms
Windows Forms
A set of .NET Framework managed libraries for developing graphical user interfaces.
1,817 questions
.NET
.NET
Microsoft Technologies based on the .NET software framework.
3,329 questions
SQL Server
SQL Server
A family of Microsoft relational database management and analysis systems for e-commerce, line-of-business, and data warehousing solutions.
12,607 questions
VB
VB
An object-oriented programming language developed by Microsoft that is implemented on the .NET Framework. Previously known as Visual Basic .NET.
2,561 questions
.NET Runtime
.NET Runtime
.NET: Microsoft Technologies based on the .NET software framework.Runtime: An environment required to run apps that aren't compiled to machine language.
1,117 questions
0 comments No comments
{count} votes

4 answers

Sort by: Most helpful
  1. Dan Guzman 9,201 Reputation points
    2022-05-20T19:48:44.807+00:00

    Use single quotes instead of double-quotes to enclose values like file names. I also suggest you ditch the device (unless you have special needs not evident here) and use a DISK= specification instead. The resultant SQL script should be like:

    BACKUP DATABASE [contactlist2.mdf 12/8/2021 6:13:57 pm]   
     TO DISK = 'C:\ProgramData\Robert Alan Gustafson II\Social Contacts Tracker\1.0.0.0\ContactList2.bak';  
    RESTORE FILELISTONLY   
     FROM DISK = 'C:\ProgramData\Robert Alan Gustafson II\Social Contacts Tracker\1.0.0.0\ContactList2.bak';  
    RESTORE DATABASE [contactlist3.mdf 5/20/2022 3:35:54 am]   
     FROM DISK = 'C:\ProgramData\Robert Alan Gustafson II\Social Contacts Tracker\1.0.0.0\ContactList2.bak'  
     WITH MOVE 'contactlist2.mdf 12/8/2021 6:13:57 pm_Data' TO 'C:\ProgramData\Robert Alan Gustafson II\Social Contacts Tracker\1.0.0.0\ContactList3.mdf'  
     , MOVE 'contactlist2.mdf 12/8/2021 6:13:57 pm_Log' TO 'C:\ProgramData\Robert Alan Gustafson II\Social Contacts Tracker\1.0.0.0\ContactList3_log.ldf';  
    

    PS. What's the best SQL for moving (not copying) a database to a new catalog, data file, and log file?
    PPS. Remember, none of what I'm doing is across machines or across servers (although it could be in the future).

    Backup/restore is is a good solution. IMHO. For your future need, to copy to a remote server be aware that you would need to setup a share and permissions such that the SQL Server service account has the necessary rights. An alternative if your database isn't particular large is a bacpac export/import, in which case the account the app runs under needs permissions to the share.

    1 person found this answer helpful.

  2. Bruce (SqlWork.com) 54,626 Reputation points
    2022-05-20T19:40:31.897+00:00

    sqlserver uses single quotes for literals, double quotes (or []) are to use reserved words as column or table names.


  3. Erland Sommarskog 100.8K Reputation points MVP
    2022-05-20T21:23:49.933+00:00

    In addition to what Dan and Bruce said, these statements are OK:

    USE master;
    EXEC sp_addumpdevice "disk", "contactlist2.mdf 12/8/2021 6:13:_TEMP", "C:\ProgramData\Robert Alan Gustafson II\Social Contacts Tracker\1.0.0.0\ContactList2.bak";
    BACKUP DATABASE "contactlist2.mdf 12/8/2021 6:13:57 pm" TO "contactlist2.mdf 12/8/2021 6:13:_TEMP";
    RESTORE FILELISTONLY FROM "contactlist2.mdf 12/8/2021 6:13:_TEMP";
    

    But I am not surprised if Dan or Bruce were confused; my initial reaction was the same. Backup devices are a very old feature in SQL Server, but they are very little used today, but I have one environment where I use one or two out of habit.

    However this statement is incorrect:

    RESTORE DATABASE "contactlist3.mdf 5/20/2022 3:35:54 am" FROM "contactlist2.mdf 12/8/2021 6:13:_TEMP" 
        WITH MOVE "contactlist2.mdf 12/8/2021 6:13:57 pm_Data" TO "C:\ProgramData\Robert Alan Gustafson II\Social Contacts Tracker\1.0.0.0\ContactList3.mdf", 
             MOVE "contactlist2.mdf 12/8/2021 6:13:57 pm_Log" TO "C:\ProgramData\Robert Alan Gustafson II\Social Contacts Tracker\1.0.0.0\ContactList3_log.ldf";
    

    The MOVE and TO clauses can not be followed by identifiers, they must be followed by string literals.

    As Dan and Bruce pointed out single and double quotes are not interchangeable in SQL, just like they are not interchangeable in many other languages. In SQL the single quote ' serves as a string delimiter, whereas the double quote " quotes identifiers. Thereby, you can have table name that includes spaces or other special characters. Or column names that are reserved keywords. For for that matter dump devices with slashes in their names.

    In SQL Server, you can also use the brackets [] for the same purpose. While the double quote is ANSI standards, and the brackets are proprietary, the brackets are far more widely used in the SQL Server world.


  4. Erland Sommarskog 100.8K Reputation points MVP
    2022-05-22T13:13:18.95+00:00

    Logical file 'contactlist2.mdf 12/8/2021 6:13:57 pm_Data' is not part of database 'contactlist3.mdf 5/22/2022 3:29:32 am'. Use RESTORE FILELISTONLY to list the logical file names

    You have this code:

                & "RESTORE DATABASE """ & DestinationCatalogName _
                   & """ FROM DISK='" & BackupFileName _
                       & "' WITH MOVE '" & SourceCatalogName & "_Data' TO '" _
    

    That is, you assume that the logical name of the data file is the same as the database name with _Data tacked on. This assumption is somewhat brave.

    If you simply say:

    CREATE DATABASE MyDB
    

    The logical name of the data file will be MyDbB and the log file will have the name MyDB_log. If you use the UI in SSMS it may use different defaults. If you restore the database under a different name, the logical names will not change. Thus, it is precarious to make assumptions about the name.

    Use sys.database_files to find out what the names actually are.

    If you want to play really safe, you should not assume that there are exactly two files. Then again, for smaller databases it is quite common that there are only two files.