Skip to content

Commit 663b108

Browse files
DOC-4744 added updated SQL Server prep instructions
1 parent 0bf0f69 commit 663b108

File tree

1 file changed

+114
-69
lines changed
  • content/integrate/redis-data-integration/data-pipelines/prepare-dbs

1 file changed

+114
-69
lines changed

content/integrate/redis-data-integration/data-pipelines/prepare-dbs/sql-server.md

Lines changed: 114 additions & 69 deletions
Original file line numberDiff line numberDiff line change
@@ -16,66 +16,82 @@ type: integration
1616
weight: 2
1717
---
1818

19-
To prepare your SQL Server database for Debezium, you must first run a query to
20-
enable CDC globally and then separately enable CDC for each table you want to
19+
To prepare your SQL Server database for Debezium, you must first create a dedicated Debezium user,
20+
run a script to enable CDC globally and then separately enable CDC for each table you want to
2121
capture. You need administrator privileges to do this.
2222

2323
Once you enable CDC, it captures all of the INSERT, UPDATE, and DELETE operations
24-
on your chosen tables. The Debezium connector can then emit these events to
25-
[Kafka topics](https://kafka.apache.org/intro#intro_concepts_and_terms).
24+
on your chosen tables. The Debezium connector can then emit these events to RDI.
2625

27-
## 1. Enable CDC on the database
26+
## 1. Create a Debezium user
2827

29-
There are two system stored procedures to enable CDC (you need
30-
administrator privileges to run these). Use `sys.sp_cdc_enable_db`
31-
to enable CDC for the whole database and then
32-
You can run the procedure with SQL Server Management Studio or with
33-
Transact-SQL.
34-
35-
Before running the procedure, ensure that:
36-
37-
- You are a member of the `sysadmin` fixed server role for the SQL Server.
38-
- You are a `db_owner` of the database.
39-
- The SQL Server Agent is running.
40-
41-
Then, follow the steps below to enable CDC:
28+
It is strongly recommended to create a dedicated Debezium user for the connection between RDI
29+
and the source database. When using an existing user, ensure that the required
30+
permissions are granted and that the user is added to the CDC role.
4231

43-
1. From the **View** menu in SQL Server Management Studio, click **Template Explorer**.
32+
1. Create a user with the Transact-SQL below:
4433

45-
1. In the Template Browser, expand **SQL Server Templates**.
34+
```sql
35+
USE master
36+
GO
37+
CREATE LOGIN MyUser WITH PASSWORD = 'My_Password'
38+
GO
39+
USE MyDB
40+
GO
41+
CREATE USER MyUser FOR LOGIN MyUser
42+
GO
43+
```
4644

47-
1. Expand **Change Data Capture > Configuration** and then click **Enable Database for CDC**.
45+
Replace `MyUser`, `My_Password` and `MyDB` with your chosen values.
4846

49-
1. In the template, replace the database name in the `USE` statement with the name of the
50-
database where you want to enable CDC. For example, if your database was called
51-
`myDB`, the template would be:
47+
1. Grant required permissions:
5248

5349
```sql
50+
USE master
51+
GO
52+
GRANT VIEW SERVER STATE TO MyUser
53+
GO
5454
USE MyDB
5555
GO
56-
EXEC sys.sp_cdc_enable_db
56+
EXEC sp_addrolemember N'db_datareader', N'MyUser'
5757
GO
5858
```
5959

60-
1. Run the stored procedure `sys.sp_cdc_enable_db` to enable CDC for the database.
60+
## 2. Enable CDC on the database
6161

62-
When you enable CDC for the database, it creates a schema called `cdc` and also
63-
a CDC user, metadata tables, and other system objects.
62+
There are two system stored procedures to enable CDC (you need
63+
administrator privileges to run these). Use `sys.sp_cdc_enable_db`
64+
to enable CDC for the whole database and then `sys.sp_cdc_enable_table` to enable CDC for individual tables.
65+
66+
Before running the procedures, ensure that:
6467

65-
Keep the **Change Data Capture > Configuration** foldout open in the Template Explorer
66-
because you will need it to enable CDC on the individual tables next.
68+
- You are a member of the `sysadmin` fixed server role for the SQL Server.
69+
- You are a `db_owner` of the database.
70+
- The SQL Server Agent is running.
71+
72+
Then, assuming your database is called `MyDB`, run the script below to enable CDC:
6773

68-
## 2. Enable CDC for the tables you want to capture
74+
```sql
75+
USE MyDB
76+
GO
77+
EXEC sys.sp_cdc_enable_db
78+
GO
79+
```
6980

70-
You must also enable CDC on the tables you want Debezium to capture using the
71-
following steps (again, you need administrator privileges for this):
81+
{{< note >}}For SQL Server on AWS RDS, you must use a different stored procedure:
82+
```sql
83+
EXEC msdb.dbo.rds_cdc_enable_db 'Chinook'
84+
GO
85+
```
86+
{{< /note >}}
87+
88+
When you enable CDC for the database, it creates a schema called `cdc` and also
89+
a CDC user, metadata tables, and other system objects.
7290

73-
1. With the **Change Data Capture > Configuration** foldout still open in the
74-
Template Explorer, select **Enable Table Specifying Filegroup Option**.
91+
## 3. Enable CDC for the tables you want to capture
7592

76-
1. In the template, replace the table name in the USE statement with the name of
77-
the table you want to capture. For example, if your table was called `MyTable`
78-
then the template would look like the following:
93+
1. You must also enable CDC on the tables you want Debezium to capture using the
94+
following commands (again, you need administrator privileges for this):
7995

8096
```sql
8197
USE MyDB
@@ -85,38 +101,34 @@ following steps (again, you need administrator privileges for this):
85101
@source_schema = N'dbo',
86102
@source_name = N'MyTable',
87103
@role_name = N'MyRole',
88-
@filegroup_name = N'MyDB_CT',
89104
@supports_net_changes = 0
90105
GO
91106
```
107+
108+
Repeat this for every table you want to capture.
109+
110+
{{< note >}}The value for `@role_name` can’t be a fixed database role, such as `db_datareader`.
111+
Specifying a new name will create a corresponding database role that has full access to the
112+
captured change data.
113+
{{< /note >}}
92114

93-
1. Run the stored procedure `sys.sp_cdc_enable_table` to enable CDC for
94-
the table.
115+
1. Add the Debezium user to the CDC role:
95116

96-
1. Repeat steps 1 to 3 for every table you want to capture.
117+
```sql
118+
USE MyDB
119+
GO
120+
EXEC sp_addrolemember N'MyRole', N'MyUser'
121+
GO
122+
```
97123

98-
## 3. Check that you have access to the CDC table
124+
## 4. Check that you have access to the CDC table
99125

100126
You can use another stored procedure `sys.sp_cdc_help_change_data_capture`
101127
to query the CDC information for the database and check you have enabled
102-
it correctly. Before doing this, check that:
103-
104-
* You have `SELECT` permission on all of the captured columns of the capture instance.
105-
If you are a member of the `db_owner` database role then you can view information for
106-
all of the defined capture instances.
107-
* You are a member of any gating roles that are defined for the table that the query includes.
108-
109-
Follow the steps below to run `sys.sp_cdc_help_change_data_capture`:
110-
111-
1. From the **View** menu in SQL Server Management Studio, click **Object Explorer**.
112-
113-
1. From the Object Explorer, expand **Databases**, and then expand your database
114-
object, for example, `MyDB`.
115-
116-
1. Expand **Programmability > Stored Procedures > System Stored Procedures**.
128+
it correctly. To do this, connect as the Debezium user you created previously (`MyUser`).
117129

118130
1. Run the `sys.sp_cdc_help_change_data_capture` stored procedure to query
119-
the table. For example, if your database was called `MyDB` then you would
131+
the CDC configuration. For example, if your database was called `MyDB` then you would
120132
run the following:
121133

122134
```sql
@@ -131,14 +143,31 @@ Follow the steps below to run `sys.sp_cdc_help_change_data_capture`:
131143
access. If the result is empty then you should check that you have privileges
132144
to access both the capture instance and the CDC tables.
133145

134-
## SQL Server on Azure
146+
### Troubleshooting
135147

136-
You can also use the Debezium SQL Server connector with SQL Server on Azure.
137-
See Microsoft's guide to
138-
[configuring SQL Server on Azure for CDC with Debezium](https://learn.microsoft.com/en-us/samples/azure-samples/azure-sql-db-change-stream-debezium/azure-sql%2D%2Dsql-server-change-stream-with-debezium/)
139-
for more information.
148+
If no CDC is happening then it might mean that SQL Server Agent is down. You can check for this using the SQL query shown below:
149+
150+
```sql
151+
IF EXISTS (SELECT 1
152+
FROM master.dbo.sysprocesses
153+
WHERE program_name = N'SQLAgent - Generic Refresher')
154+
BEGIN
155+
SELECT @@SERVERNAME AS 'InstanceName', 1 AS 'SQLServerAgentRunning'
156+
END
157+
ELSE
158+
BEGIN
159+
SELECT @@SERVERNAME AS 'InstanceName', 0 AS 'SQLServerAgentRunning'
160+
END
161+
```
162+
163+
If the query returns a result of 0, you need to need to start SQL Server Agent using the following commands:
140164

141-
### SQL Server capture job agent configuration parameters
165+
```sql
166+
EXEC xp_servicecontrol N'START',N'SQLServerAGENT';
167+
GO
168+
```
169+
170+
## SQL Server capture job agent configuration parameters
142171

143172
In SQL Server, the parameters that control the behavior of the capture job agent
144173
are defined in the SQL Server table `msdb.dbo.cdc_jobs`. If you experience performance
@@ -169,6 +198,13 @@ of the Debezium SQL Server connector:
169198

170199
See the SQL Server documentation for more information about capture agent parameters.
171200

201+
## SQL Server on Azure
202+
203+
You can also use the Debezium SQL Server connector with SQL Server on Azure.
204+
See Microsoft's guide to
205+
[configuring SQL Server on Azure for CDC with Debezium](https://learn.microsoft.com/en-us/samples/azure-samples/azure-sql-db-change-stream-debezium/azure-sql%2D%2Dsql-server-change-stream-with-debezium/)
206+
for more information.
207+
172208
## Handling changes to the schema
173209
174210
RDI can't adapt automatically when you change the schema of a CDC table in SQL Server. For example,
@@ -186,19 +222,28 @@ documentation for further details.
186222
187223
1. Create a new capture table for the updated source table by running the `sys.sp_cdc_enable_table` stored
188224
procedure with a new, unique value for the parameter `@capture_instance`. For example, if the old value
189-
was `dbo_customers`, you could replace it with `dbo_customers_v2`:
225+
was `dbo_MyTable`, you could replace it with `dbo_MyTable_v2` (you can see the existing values by running
226+
stored procedure `sys.sp_cdc_help_change_data_capture`):
190227
191228
```sql
192-
EXEC sys.sp_cdc_enable_table @source_schema = 'dbo', @source_name = 'customers', @role_name = NULL, @supports_net_changes = 0, @capture_instance = 'dbo_customers_v2';
229+
EXEC sys.sp_cdc_enable_table
230+
@source_schema = N'dbo',
231+
@source_name = N'MyTable',
232+
@role_name = N'MyRole',
233+
@capture_instance = N'dbo_MyTable_v2',
234+
@supports_net_changes = 0
193235
GO
194236
```
195237
196238
1. When Debezium starts streaming from the new capture table, drop the old capture table by running
197239
the `sys.sp_cdc_disable_table` stored procedure with the parameter `@capture_instance` set to the old
198-
capture instance name, `dbo_customers`:
240+
capture instance name, `dbo_MyTable`:
199241
200242
```sql
201-
EXEC sys.sp_cdc_disable_table @source_schema = 'dbo', @source_name = 'dbo_customers', @capture_instance = 'dbo_customers';
243+
EXEC sys.sp_cdc_disable_table
244+
@source_schema = N'dbo',
245+
@source_name = N'MyTable',
246+
@capture_instance = N'dbo_MyTable'
202247
GO
203248
```
204249

0 commit comments

Comments
 (0)