@@ -593,4 +593,98 @@ EXEC [sys].[sp_cdc_disable_table]
593
593
@source_name = @source_name,
594
594
@capture_instance = @capture_instance_temp
595
595
596
+ ```
597
+
598
+ ## Code to manage structural changes (DDL) to tables being captured.
599
+
600
+ The following code is a variant of the code above in a packaged form.
601
+
602
+ This may assist the process of maintaining CDC tables when the base table has a structural change.
603
+
604
+ ``` sql
605
+ -- Automated sqlserver-cdc-re-enrolled procedures.
606
+
607
+ CREATE PROCEDURE [mydatabase].[DisableCDC]
608
+ @schema_name NVARCHAR(512 ),
609
+ @table_name NVARCHAR(512 )
610
+ AS
611
+ BEGIN
612
+ DECLARE @capture_instance NVARCHAR(512 ) = @schema_name + ' _' + @table_name;
613
+ EXEC sys .sp_cdc_disable_table
614
+ @source_schema = @schema_name,
615
+ @source_name = @table_name,
616
+ @capture_instance = @capture_instance
617
+ END;
618
+ GO
619
+ CREATE PROCEDURE [mydatabase].[EnableCDC]
620
+ @schema_name NVARCHAR(512 ),
621
+ @table_name NVARCHAR(512 )
622
+ AS
623
+ BEGIN
624
+ EXEC sys .sp_cdc_enable_table
625
+ @source_schema = @schema_name,
626
+ @source_name = @table_name,
627
+ @role_name = RoleChangeDataCapture,
628
+ @supports_net_changes = 1
629
+ END;
630
+ GO
631
+ create procedure [mydatabase].[ReEnrollCDCTable]
632
+ @source_schema varchar (max),
633
+ @source_name varchar (max)
634
+ as
635
+ begin
636
+ declare @cdc_schema varchar (max) = ' cdc'
637
+ declare @column_list varchar (max)
638
+ declare @sql varchar (max)
639
+ declare @capture_instance varchar (max)
640
+ set @capture_instance = @source_schema + ' _' + @source_name
641
+ declare @ct_table varchar (max)
642
+ set @ct_table = @capture_instance + ' _ct'
643
+ declare @capture_instance_temp varchar (max)
644
+ set @capture_instance_temp = @capture_instance + ' _temp'
645
+ declare @ct_table_temp varchar (max)
646
+ set @ct_table_temp = @capture_instance_temp + ' _ct'
647
+ exec sys .sp_cdc_enable_table
648
+ @source_schema = @source_schema,
649
+ @source_name = @source_name,
650
+ @role_name = N' RoleChangeDataCapture' ,
651
+ @supports_net_changes = 1 ,
652
+ @capture_instance = @capture_instance_temp
653
+ select @column_list = stuff((
654
+ select ' ,' + column_name
655
+ from (
656
+ select ct .column_name
657
+ from information_schema .columns ct
658
+ inner join information_schema .columns ctt
659
+ on ct .column_name = ctt .column_name
660
+ where ct .table_name = @ct_table and ct .table_schema = @cdc_schema
661
+ and ctt .table_name = @ct_table_temp and ctt .table_schema = @cdc_schema
662
+ ) x
663
+ for xml path (' ' )), 1 , 1 , ' ' )
664
+ set @sql = ' insert into ' + @cdc_schema + ' .' + @ct_table_temp +
665
+ ' (' + @column_list + ' ) select ' + @column_list +
666
+ ' from ' + @cdc_schema + ' .' + @ct_table
667
+ exec(@sql)
668
+ exec dbo .disablecdc @source_schema,@source_name;
669
+ exec dbo .enablecdc @source_schema,@source_name;
670
+ set @sql = ' insert into ' + @cdc_schema + ' .' + @ct_table +
671
+ ' (' + @column_list + ' ) select ' + @column_list +
672
+ ' from ' + @cdc_schema + ' .' + @ct_table_temp
673
+ exec(@sql)
674
+ exec sys .sp_cdc_disable_table
675
+ @source_schema = @source_schema,
676
+ @source_name = @source_name,
677
+ @capture_instance = @capture_instance_temp
678
+ end
679
+ go
680
+
681
+ -- Example-cdc-re-enroll-tables
682
+
683
+ -- Stop the CDC processing
684
+ exec sp_cdc_stop_job
685
+ -- Align CDC tables with new table structure
686
+ exec mydatabase .ReEnrollCDCTable ' schema1' ,' table_a'
687
+ exec mydatabase .ReEnrollCDCTable ' schema2' ,' table_b'
688
+ -- Restart the CDC processing
689
+ exec sp_cdc_start_job
596
690
```
0 commit comments