Moving the Historian Runtime Database to Another Machine Using SQL Server 2012

LEGACY TECH NOTE #

1035
SUMMARY

It is sometimes necessary to move a Runtime database from one Historian Server computer to another. Tech Note #817 Moving the Historian Runtime Database From one Machine to Another describes this process for SQL Server 2005 and SQL Server 2008; however, several of the stored procedures used in that Tech Note have been deprecated in SQL Server 2012.

This Tech Note provides step-by-step procedures to guide you through this process using SQL Server 2012 and later.

Application Versions

  • Historian Server 11.0 or later
  • Microsoft SQL Server 2012 (32-bit or 64-bit)

Note: This Tech Note assumes that you are familiar with Wonderware Historian Server and Microsoft SQL Server Management Studio. If you have any questions regarding the Microsoft SQL Server, contact Microsoft Technical support at www.microsoft.com for further assistance.

ACTION

This process consists of the following tasks:

Back Up the Runtime Database

The first task is to back up the Runtime Database on the existing server.

  1. Start Microsoft SQL Server Management Studio (Figure 1 below). Make sure to login to the SQL Server using either the sa login or your Windows-Authenticated account with local administrative privileges.
  2. Expand the tree on the left panel until you see Databases + Runtime.


    Figure 1: SQL Server Management Studio

  3. Right-click the Runtime Database and click Tasks/Back Up (Figure 2 below).


    Figure 2: Database Tasks/Back Up

  4. When the Back Up Database – Runtime dialog box (Figure 3 below) appears, make note of the Destination path for the backup file. The default is …\Microsoft SQL Server\MSSQL 10.MSSQLSERVER\MSSQL\BACKUP\Runtime.bak. Your location might be different.


    Figure 3: SQL Server Backup Database – General Page

  5. Click the Options list item. In the Overwrite media section, click Back up to the existing Media set and Append to the existing backup set.
  6. In the Reliability section, click the Verify backup when finished option.
  7. Click OK to continue.


    Figure 4: SQL Server Backup Database – Options Page

  8. After several moments a confirmation message appears (Figure 5 below). Click OK.


    Figure 5: Backup Completed Successfully

Restore the Runtime Database to the New Server

This section describes the steps to restore the Runtime database onto the new destination server.

This Tech Note assumes that Historian Server is installed on the new machine.

  1. Open the SMC, and expand the ArchestrA System Management Console + Historian.
  2. Expand the Historian Group/<LocalMachine>/Management Console.
  3. Right-click Status and click All Tasks/Shutdown (and Disable) Historian.


    Figure 6: Shutdown (and Disable) Historian

  4. Start the Microsoft SQL Server Management Studio. Make sure to login to SQL Server using either the sa login or your Windows-Authenticated account with local Administrative privileges.
  5. Open a new query window and copy/paste the following Transact-SQL code into the query area and execute it. This query will rename the existing Runtime database on the destination server to Runtime_Old for safety purposes.

    USE Master
    GO
    ALTER DATABASE Runtime SET SINGLE_USER;
    ALTER DATABASE Runtime MODIFY NAME = Runtime_Old;
    GO

  6. NOTE: If using Historian Server v11.6 (from System Platform 2014-R2) you need to detach the Runtime_Old database and rename its *.MDF & *.LDF files to avoid name collision with your upcoming new Runtime database:

    USE Master
    GO
    ALTER DATABASE Runtime_OLD SET SINGLE_USER
    GO
    EXEC sp_detach_db ‘Runtime_OLD’
    GO
    ‘!!! Stop here and manually rename the physical files before running Historian Configurator !!!’
    /* OPTIONAL = You don’t have to re-attach the old files if you don’t want to, but here’s a script
    in case you do.  You may need to modify these folder paths and file names to match your system …
    */

    EXEC sp_attach_db ‘Runtime_OLD’
    , @filename1 = ‘C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\DATA\RuntimeDat_116_OLD.mdf’
    , @filename2 = ‘C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\DATA\RuntimeLog_116_OLD.ldf’

    GO

  7. Copy the Runtime backup file from the path in Step 4 in the previous section to a folder on the destination Server.
  8. From the MS SQL Server Management Studio, right-click the Database folder and click Restore Database. The Restore Database dialog appears.
  9. Choose the Device option, then click the Ellipsis button to locate to the folder where you copied the Runtime.bak file (Step 6 in this procedure).
  10. The Select Backup Devices dialog box appears. Click the Add button, browse to the folder, select the Runtime.bak backup file (Figure 7 below), then click OK twice to return to the Restore Database dialog box.


    Figure 7: Restore Database – Runtime and Locate Runtime Backup File

  11. Type the database name Runtime in the Destination Database field.
  12. Make sure the Restore option is selected for the Runtime database in the Backup Sets to Restore (Figure 8 below).


    Figure 8: Restore Database – Runtime Dialog Box

  13. On the Restore Database – Runtime panel, click Files.
  14. If necessary, modify the paths for the Data file (MDF) and Log file (LDF) in the Restore As column Figure 9 (below):


    Figure 9: Restore Database/Options Panel

  15. You can click on the Options area of the Restore Database – Runtime panel if you wish to modify any further options, but for simplicity we recommend keeping the default settings when possible.
  16. Click OK to begin the restore process.
  17. After the restore operation completes successfully, execute the following Transact-SQL script from the MS SQL Server Management Studio to ensure that all of the Historian Server’s pre-configured user accounts and roles are properly connected.

    USE Runtime;

ALTER USER wwAdmin WITH LOGIN = wwAdmin;
ALTER LOGIN wwAdmin WITH DEFAULT_DATABASE = Runtime;
ALTER USER wwUser WITH LOGIN = wwUser;
ALTER LOGIN wwUser WITH DEFAULT_DATABASE = Runtime;
ALTER USER wwPower WITH LOGIN = wwPower;
ALTER LOGIN wwPower WITH DEFAULT_DATABASE = Runtime;

ALTER AUTHORIZATION ON DATABASE::Runtime TO wwdbo;

ALTER USER aaAdmin WITH LOGIN = aaAdmin;
ALTER LOGIN aaAdmin WITH DEFAULT_DATABASE = Runtime;
ALTER USER aaUser WITH LOGIN = aaUser;
ALTER LOGIN aaUser WITH DEFAULT_DATABASE = Runtime;
ALTER USER aaPower WITH LOGIN = aaPower;
ALTER LOGIN aaPower WITH DEFAULT_DATABASE = Runtime;

ALTER AUTHORIZATION ON DATABASE::Runtime TO aadbo;

Complete the Configuration on the New Server

The final task is to update the Node Name and Data Paths on the new machine.

Once the Runtime Database has been moved, you must modify the Runtime configuration settings to reflect the node name where the new installation resides. Also, if the drive or path where the History Blocks are stored has changed from the old existing node, these configuration settings must also be modified.

  1. Make sure the Historian Server is still shutdown and disabled.
  2. Copy and modify the following Transact-SQL statements for the Historian Server to run on the new node. Substitute NewNodeName and OldNodeName with your appropriate computer names where necessary.

    • The ComputerName field in the StorageNode table contains the node name where the Historian Server data is logged.

UPDATE StorageNode
SET ComputerName = ‘NewNodeName’
WHERE ComputerName = ‘OldNodeName’

• The ComputerName field in the ServerList table also contains the node name where the Historian Server resides.

UPDATE ServerList
SET ComputerName = ‘NewNodeName’
WHERE ComputerName = ‘OldNodeName’

• The MachineName field in the InTouchNode table contains the names of all nodes from which the InTouch tagname databases have been imported. You only need to modify this table if the Historian Server tags were imported from an InTouch application that was local to the Historian Server on the old computer and has also been moved to this new computer.

UPDATE InTouchNode
SET MachineName = ‘NewNodeName’
WHERE MachineName = ‘OldNodeName’

• The ComputerName field in the IODriver table also contains the node name where the Historian Server resides.

UPDATE IODriver
SET ComputerName = ‘NewNodeName’
WHERE ComputerName = ‘OldNodeName’

• The ComputerName field in the IOServer table contains the node names where the internal System Driver (SysDrv) and various I/O Servers or DAServers for IDAS data collection are installed. If any I/O sources that were running locally to the Historian Server on the old node are not going to be running locally on the new node, you will need to manually modify the IOServer entries afterward using Historian Server Configuration Editor (SMC).

UPDATE IOServer
SET ComputerName = ‘NewNodeName’
WHERE ComputerName = ‘OldNodeName’

• Run the following statements only if the drive or path selected for the Historian Server storage locations (Circular, Buffer, Permanent, Alternate) was changed with the new installation. Before making any modifications to the StorageLocation paths, run the following SELECT statement and use Windows Explorer to confirm the paths listed.

SELECT * FROM StorageLocation

• If necessary, use the statements below to modify any paths that are different on this node. Replace the drive letter “x” in the following code with the drive letter that is appropriate for your installation.

UPDATE StorageLocation
SET path = ‘x:\Historian\DATA\Circular’
WHERE StorageType = 1
UPDATE StorageLocation
SET path = ‘x:\Historian\DATA\Buffer’
WHERE StorageType = 3
UPDATE StorageLocation
SET path = ‘x:\Historian\DATA\Permanent’
WHERE StorageType = 4

  1. Enable and restart the Historian Server from the SMC by right-clicking Status and clicking All Tasks/Enable (allow to run) Historian.
  2. If the System Parameter for AutoStart is not enabled, right-click Status and click Start Historian.

 

Leave a Reply

Your email address will not be published. Required fields are marked *

25 − = 23