Help Center/ Relational Database Service/ Best Practices/ RDS for SQL Server/ Using DAS to Create and Configure Agent Job and DBLink on the Master and Slave Databases for RDS for SQL Server Instances
Updated on 2024-09-06 GMT+08:00

Using DAS to Create and Configure Agent Job and DBLink on the Master and Slave Databases for RDS for SQL Server Instances

Scenarios

Data Admin Service (DAS) is a one-stop database management platform that allows you to manage databases on a web console. It offers database development, O&M, and intelligent diagnosis, facilitating your database usage and maintenance. Currently, DAS supports primary/standby switchover of RDS for SQL Server databases, facilitating synchronization between master and slave databases.

Logging In to DAS

  1. Log in to the management console.
  2. Click in the upper left corner and select a region and a project.
  3. Click in the upper left corner of the page and choose Databases > Relational Database Service.
  4. On the Instances page, locate the target DB instance and click Log In in the Operation column.

    Alternatively, click the instance name on the Instances page. On the displayed Basic Information page, click Log In in the upper right corner of the page.

  5. On the displayed login page, enter the correct username and password and click Log In.

Creating a Job for Data Synchronization to the Slave Database

  1. Create a job on the master database.

    On the DAS console, choose SQL Operations > SQL Query on the top menu bar. In the msdb database, run the following commands to create a job:

    If a job has been created on the master database, skip this step.

    USE [msdb]
    GO
    DECLARE @jobId BINARY(16)
    EXEC  msdb.dbo.sp_add_job @job_name=N'hwtest', 
                       @enabled=1, 
                       @notify_level_eventlog=0, 
                       @notify_level_email=2, 
                       @notify_level_page=2, 
                       @delete_level=0, 
                       @category_name=N'[Uncategorized (Local)]', 
                       @owner_login_name=N'rdsuser', @job_id = @jobId OUTPUT
    select @jobId
    GO
    EXEC msdb.dbo.sp_add_jobserver @job_name=N'hwtest', @server_name = N'*******'
    GO
    USE [msdb]
    GO
    EXEC msdb.dbo.sp_add_jobstep @job_name=N'hwtest', @step_name=N'select orders', 
                       @step_id=1, 
                       @cmdexec_success_code=0, 
                       @on_success_action=1, 
                       @on_fail_action=2, 
                       @retry_attempts=0, 
                       @retry_interval=0, 
                       @os_run_priority=0, @subsystem=N'TSQL', 
                       @command=N'select * from orders;', 
                       @database_name=N'test', 
                       @flags=0
    GO
    USE [msdb]
    GO
    EXEC msdb.dbo.sp_update_job @job_name=N'hwtest', 
                       @enabled=1, 
                       @start_step_id=1, 
                       @notify_level_eventlog=0, 
                       @notify_level_email=2, 
                       @notify_level_page=2, 
                       @delete_level=0, 
                       @description=N'', 
                       @category_name=N'[Uncategorized (Local)]', 
                       @owner_login_name=N'zf1', 
                       @notify_email_operator_name=N'', 
                       @notify_page_operator_name=N''
    GO

    Run the following SQL statements to check whether the job has been created:

    use [msdb]

    select * from msdb.dbo.sysjobs where name ='hwtest';

  2. Switch to the slave database.

    Currently, RDS for SQL Server does not support job synchronization between the master and slave databases. Therefore, you need to create a job on the slave database and synchronize the job. Click Switch SQL Execution Node next to Master to switch to the slave database.

  3. Run the commands in 1 to create a job on the slave database.

    Alternatively, use SQL Server Management Studio (SSMS) to export the created job to the editor window, copy the job to the SQL query window, and then run the commands in 1 to create a job on the slave database.

    If the job fails to be created, you are advised to delete the job first and then create the job again.

    Figure 1 Exporting a job
    Figure 2 Using the DAS console to create a job on the slave database

    Run the following SQL statements to delete the job:

    USE [msdb]

    GO

    EXEC msdb.dbo.sp_delete_job @job_name=N'hwtest', @delete_unused_schedule=1

    GO

Creating a DBLink for Data Synchronization to the Slave Database

DAS allows you to create linked servers to synchronize data between master and slave databases.

Check whether the MSDTC is configured by referring to Creating a Linked Server for an RDS for SQL Server DB Instance.

  1. Create a DBLink on the master database.

    USE [master]

    GO

    EXEC master.dbo.sp_addlinkedserver @server = N'TEST', @srvproduct=N'mytest', @provider=N'SQLOLEDB', @datasrc=N'abcd'

    EXEC master.dbo.sp_addlinkedsrvlogin @rmtsrvname = N'TEST', @locallogin = NULL , @useself = N'False', @rmtuser = N'rdsuser', @rmtpassword = N'********'

    GO

    After the creation is successful, the corresponding DB instance or databases can be linked to view data verification. Run the following statements to query databases:

    SELECT name FROM [TEST].master.sys.databases ;

    GO

    Figure 3 Database query

  2. Create a DBLink on the slave database.

    On the DAS console, click Switch SQL Execution Node next to Master and run the SQL statement for creating a DBLink.

    If the current DB instance and the interconnected database are not in the same VPC or distributed transactions are enabled with an EIP bound to the primary DB instance, the query statement cannot be executed on the standby DB instance. This step is used only to synchronize the DBLink configuration. After a switchover or failover, the DBLink can be used.