├── docker-compose.yaml ├── go.mod ├── init.sql ├── README.md ├── validator.go ├── go.sum └── main.go /docker-compose.yaml: -------------------------------------------------------------------------------- 1 | version: '3.8' 2 | 3 | services: 4 | sqlserver: 5 | image: mcr.microsoft.com/mssql/server:2022-latest 6 | container_name: sqlserver 7 | environment: 8 | ACCEPT_EULA: "Y" 9 | MSSQL_SA_PASSWORD: "YourStrong!Passw0rd" 10 | MSSQL_AGENT_ENABLED: true 11 | ports: 12 | - "1433:1433" 13 | -------------------------------------------------------------------------------- /go.mod: -------------------------------------------------------------------------------- 1 | module github.com/josephwoodward/cdc-poc 2 | 3 | go 1.24.5 4 | 5 | require github.com/denisenkom/go-mssqldb v0.12.3 6 | 7 | require ( 8 | github.com/golang-sql/civil v0.0.0-20190719163853-cb61b32ac6fe // indirect 9 | github.com/golang-sql/sqlexp v0.1.0 // indirect 10 | golang.org/x/crypto v0.0.0-20220622213112-05595931fe9d // indirect 11 | ) 12 | -------------------------------------------------------------------------------- /init.sql: -------------------------------------------------------------------------------- 1 | CREATE DATABASE mydb; 2 | GO 3 | 4 | USE mydb; 5 | GO 6 | 7 | -- enable CDC on server 8 | EXEC sys.sp_cdc_enable_db 9 | GO 10 | 11 | -- create users table for test data 12 | CREATE TABLE users ( 13 | id INT PRIMARY KEY, 14 | name NVARCHAR(100) 15 | ); 16 | GO 17 | 18 | -- enable CDC on table 19 | EXEC sys.sp_cdc_enable_table 20 | @source_schema = 'dbo', 21 | @source_name = 'users', 22 | @role_name = NULL; 23 | GO 24 | 25 | -- create CDC changes 26 | INSERT INTO users VALUES (1, 'Alice'), (2, 'Bob'); 27 | INSERT INTO users VALUES (3, 'Trevor'), (4, 'Amy'); 28 | DELETE FROM users WHERE id = 3; 29 | UPDATE users SET name = 'Michelle' WHERE id = 4; 30 | GO 31 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | 2 | ```bash 3 | sqlcmd -S localhost -U sa -P 'YourStrong!Passw0rd' -i init.sql 4 | ``` 5 | 6 | 7 | Enable for table: 8 | 9 | ```sql 10 | USE mydb; 11 | GO 12 | 13 | EXEC sys.sp_cdc_enable_table 14 | @source_schema = 'dbo', 15 | @source_name = 'users', 16 | @role_name = NULL; 17 | GO 18 | ``` 19 | 20 | Check if CDC is enabled: 21 | ```sql 22 | select * from sys.databases 23 | ``` 24 | and check for `is_cdc_enabled` column; 25 | 26 | Query CDC Table: 27 | 28 | ```sql 29 | USE mydb; 30 | GO 31 | 32 | SELECT * FROM cdc.dbo_users_CT; 33 | GO 34 | ``` 35 | 36 | ``` 37 | DECLARE @from_lsn binary(10) = sys.fn_cdc_get_min_lsn('dbo_users'); 38 | DECLARE @to_lsn binary(10) = sys.fn_cdc_get_max_lsn(); 39 | 40 | SELECT * 41 | FROM cdc.fn_cdc_get_all_changes_dbo_users(@from_lsn, @to_lsn, 'all'); 42 | ``` 43 | 44 | Other useful links: 45 | 46 | - https://gist.github.com/NISH1001/e1b13457f6f4515314493e7da75962f1 47 | -------------------------------------------------------------------------------- /validator.go: -------------------------------------------------------------------------------- 1 | package main 2 | 3 | import ( 4 | "fmt" 5 | "sort" 6 | ) 7 | 8 | type CDCMessage struct { 9 | LSN string `json:"lsn"` 10 | Table string `json:"table"` 11 | Operation string `json:"op"` 12 | UpdateMask []bool `json:"update_mask,omitempty"` 13 | ChangedCols []string `json:"changed_cols,omitempty"` 14 | } 15 | 16 | // Validator keeps track of seen LSNs and checks ordering 17 | type Validator struct { 18 | lastLSNPerTable map[string]string 19 | seenLSNs map[string]struct{} 20 | } 21 | 22 | func NewValidator() *Validator { 23 | return &Validator{ 24 | lastLSNPerTable: make(map[string]string), 25 | seenLSNs: make(map[string]struct{}), 26 | } 27 | } 28 | 29 | func (v *Validator) Check(msg CDCMessage) { 30 | // 1. Check for duplicate LSNs 31 | if _, exists := v.seenLSNs[msg.LSN]; exists { 32 | fmt.Printf("[ERROR] Duplicate LSN detected: %s (%s)\n", msg.LSN, msg.Table) 33 | } 34 | v.seenLSNs[msg.LSN] = struct{}{} 35 | 36 | // 2. Check ordering per table 37 | if last, ok := v.lastLSNPerTable[msg.Table]; ok && last > msg.LSN { 38 | fmt.Printf("[ERROR] Out-of-order LSN for table %s: last=%s current=%s\n", msg.Table, last, msg.LSN) 39 | } 40 | v.lastLSNPerTable[msg.Table] = msg.LSN 41 | 42 | // 3. Optional: Check update mask vs changed columns 43 | if len(msg.UpdateMask) > 0 && len(msg.ChangedCols) > 0 { 44 | maskCols := []string{} 45 | for i, changed := range msg.UpdateMask { 46 | if changed { 47 | maskCols = append(maskCols, fmt.Sprintf("col%d", i+1)) 48 | } 49 | } 50 | sort.Strings(maskCols) 51 | sort.Strings(msg.ChangedCols) 52 | 53 | if fmt.Sprintf("%v", maskCols) != fmt.Sprintf("%v", msg.ChangedCols) { 54 | fmt.Printf("[ERROR] Update mask mismatch at LSN %s: mask=%v changed=%v\n", 55 | msg.LSN, maskCols, msg.ChangedCols) 56 | } 57 | } 58 | } 59 | 60 | // func main() { 61 | // validator := NewValidator() 62 | 63 | // decoder := json.NewDecoder(os.Stdin) 64 | // for { 65 | // var msg CDCMessage 66 | // if err := decoder.Decode(&msg); err != nil { 67 | // if err == io.EOF { 68 | // break 69 | // } 70 | // fmt.Fprintf(os.Stderr, "decode error: %v\n", err) 71 | // continue 72 | // } 73 | // validator.Check(msg) 74 | // } 75 | 76 | // fmt.Println("Validation complete.") 77 | // } 78 | -------------------------------------------------------------------------------- /go.sum: -------------------------------------------------------------------------------- 1 | github.com/Azure/azure-sdk-for-go/sdk/azcore v0.19.0/go.mod h1:h6H6c8enJmmocHUbLiiGY6sx7f9i+X3m1CHdd5c6Rdw= 2 | github.com/Azure/azure-sdk-for-go/sdk/azidentity v0.11.0/go.mod h1:HcM1YX14R7CJcghJGOYCgdezslRSVzqwLf/q+4Y2r/0= 3 | github.com/Azure/azure-sdk-for-go/sdk/internal v0.7.0/go.mod h1:yqy467j36fJxcRV2TzfVZ1pCb5vxm4BtZPUdYWe/Xo8= 4 | github.com/davecgh/go-spew v1.1.0/go.mod h1:J7Y8YcW2NihsgmVo/mv3lAwl/skON4iLHjSsI+c5H38= 5 | github.com/davecgh/go-spew v1.1.1/go.mod h1:J7Y8YcW2NihsgmVo/mv3lAwl/skON4iLHjSsI+c5H38= 6 | github.com/denisenkom/go-mssqldb v0.12.3 h1:pBSGx9Tq67pBOTLmxNuirNTeB8Vjmf886Kx+8Y+8shw= 7 | github.com/denisenkom/go-mssqldb v0.12.3/go.mod h1:k0mtMFOnU+AihqFxPMiF05rtiDrorD1Vrm1KEz5hxDo= 8 | github.com/dnaeon/go-vcr v1.2.0/go.mod h1:R4UdLID7HZT3taECzJs4YgbbH6PIGXB6W/sc5OLb6RQ= 9 | github.com/golang-sql/civil v0.0.0-20190719163853-cb61b32ac6fe h1:lXe2qZdvpiX5WZkZR4hgp4KJVfY3nMkvmwbVkpv1rVY= 10 | github.com/golang-sql/civil v0.0.0-20190719163853-cb61b32ac6fe/go.mod h1:8vg3r2VgvsThLBIFL93Qb5yWzgyZWhEmBwUJWevAkK0= 11 | github.com/golang-sql/sqlexp v0.1.0 h1:ZCD6MBpcuOVfGVqsEmY5/4FtYiKz6tSyUv9LPEDei6A= 12 | github.com/golang-sql/sqlexp v0.1.0/go.mod h1:J4ad9Vo8ZCWQ2GMrC4UCQy1JpCbwU9m3EOqtpKwwwHI= 13 | github.com/modocache/gover v0.0.0-20171022184752-b58185e213c5/go.mod h1:caMODM3PzxT8aQXRPkAt8xlV/e7d7w8GM5g0fa5F0D8= 14 | github.com/pkg/browser v0.0.0-20180916011732-0a3d74bf9ce4/go.mod h1:4OwLy04Bl9Ef3GJJCoec+30X3LQs/0/m4HFRt/2LUSA= 15 | github.com/pmezard/go-difflib v1.0.0/go.mod h1:iKH77koFhYxTK1pcRnkKkqfTogsbg7gZNVY4sRDYZ/4= 16 | github.com/stretchr/objx v0.1.0/go.mod h1:HFkY916IF+rwdDfMAkV7OtwuqBVzrE8GR6GFx+wExME= 17 | github.com/stretchr/testify v1.7.0/go.mod h1:6Fq8oRcR53rry900zMqJjRRixrwX3KX962/h/Wwjteg= 18 | golang.org/x/crypto v0.0.0-20190308221718-c2843e01d9a2/go.mod h1:djNgcEr1/C05ACkg1iLfiJU5Ep61QUkGW8qpdssI0+w= 19 | golang.org/x/crypto v0.0.0-20201016220609-9e8e0b390897/go.mod h1:LzIPMQfyMNhhGPhUkYOs5KpL4U8rLKemX1yGLhDgUto= 20 | golang.org/x/crypto v0.0.0-20220622213112-05595931fe9d h1:sK3txAijHtOK88l68nt020reeT1ZdKLIYetKl95FzVY= 21 | golang.org/x/crypto v0.0.0-20220622213112-05595931fe9d/go.mod h1:IxCIyHEi3zRg3s0A5j5BB6A9Jmi73HwBIUl50j+osU4= 22 | golang.org/x/net v0.0.0-20190404232315-eb5bcb51f2a3/go.mod h1:t9HGtf8HONx5eT2rtn7q6eTqICYqUVnKs3thJo3Qplg= 23 | golang.org/x/net v0.0.0-20210610132358-84b48f89b13b/go.mod h1:9nx3DQGgdP8bBQD5qxJ1jj9UTztislL4KSBs9R2vV5Y= 24 | golang.org/x/net v0.0.0-20211112202133-69e39bad7dc2/go.mod h1:9nx3DQGgdP8bBQD5qxJ1jj9UTztislL4KSBs9R2vV5Y= 25 | golang.org/x/sys v0.0.0-20190215142949-d0b11bdaac8a/go.mod h1:STP8DvDyc/dI5b8T5hshtkjS+E42TnysNCUPdjciGhY= 26 | golang.org/x/sys v0.0.0-20190412213103-97732733099d/go.mod h1:h1NjWce9XRLGQEsW7wpKNCjG9DtNlClVuFLEZdDNbEs= 27 | golang.org/x/sys v0.0.0-20201119102817-f84b799fce68/go.mod h1:h1NjWce9XRLGQEsW7wpKNCjG9DtNlClVuFLEZdDNbEs= 28 | golang.org/x/sys v0.0.0-20210423082822-04245dca01da/go.mod h1:h1NjWce9XRLGQEsW7wpKNCjG9DtNlClVuFLEZdDNbEs= 29 | golang.org/x/sys v0.0.0-20210615035016-665e8c7367d1/go.mod h1:oPkhp1MJrh7nUepCBck5+mAzfO9JrbApNNgaTdGDITg= 30 | golang.org/x/term v0.0.0-20201126162022-7de9c90e9dd1/go.mod h1:bj7SfCRtBDWHUb9snDiAeCFNEtKQo2Wmx5Cou7ajbmo= 31 | golang.org/x/text v0.3.0/go.mod h1:NqM8EUOU14njkJ3fqMW+pc6Ldnwhi/IjpwHt7yyuwOQ= 32 | golang.org/x/text v0.3.6/go.mod h1:5Zoc/QRtKVWzQhOtBMvqHzDpF6irO9z98xDceosuGiQ= 33 | golang.org/x/tools v0.0.0-20180917221912-90fa682c2a6e/go.mod h1:n7NCudcB/nEzxVGmLbDWY5pfWTLqBcC2KZ6jyYvM4mQ= 34 | gopkg.in/check.v1 v0.0.0-20161208181325-20d25e280405/go.mod h1:Co6ibVJAznAaIkqp8huTwlJQCZ016jof/cbN4VW5Yz0= 35 | gopkg.in/yaml.v2 v2.2.8/go.mod h1:hI93XBmqTisBFMUTm0b8Fm+jr3Dg1NNxqwp+5A1VGuI= 36 | gopkg.in/yaml.v2 v2.4.0/go.mod h1:RDklbk79AGWmwhnvt/jBztapEOGDOx6ZbXqjP6csGnQ= 37 | gopkg.in/yaml.v3 v3.0.0-20200313102051-9f266ea9e77c/go.mod h1:K4uyk7z7BCEPqu6E+C64Yfv1cQ7kz7rIZviUmN+EgEM= 38 | gopkg.in/yaml.v3 v3.0.0-20210107192922-496545a6307b/go.mod h1:K4uyk7z7BCEPqu6E+C64Yfv1cQ7kz7rIZviUmN+EgEM= 39 | -------------------------------------------------------------------------------- /main.go: -------------------------------------------------------------------------------- 1 | package main 2 | 3 | import ( 4 | "context" 5 | "database/sql" 6 | "fmt" 7 | "log" 8 | "time" 9 | 10 | _ "github.com/denisenkom/go-mssqldb" 11 | ) 12 | 13 | type changeTable struct { 14 | captureInstance string 15 | startLsn []byte 16 | endLsn []byte 17 | } 18 | 19 | func main() { 20 | db, err := sql.Open("sqlserver", "sqlserver://sa:YourStrong!Passw0rd@localhost:1433?database=mydb&encrypt=disable") 21 | if err != nil { 22 | log.Fatal("Failed to connect to SQL Server:", err) 23 | } 24 | defer db.Close() 25 | 26 | var ( 27 | fromLSN []byte 28 | toLSN []byte 29 | ) 30 | 31 | // check if CDC is enabled: 32 | ct, err := cdcEnabled(db) 33 | if err != nil { 34 | log.Printf("Failed to check if cdc is enabled: %s\n", err) 35 | } 36 | 37 | users := ct["dbo_users"] 38 | fromLSN = users.startLsn 39 | // toLSN = users.endLsn 40 | 41 | // get next lsn 42 | // if err := db.QueryRowContext(context.TODO(), 43 | // "SELECT sys.fn_cdc_increment_lsn(@p1)", sql.Named("p1", lastLSN), 44 | // ).Scan(&fromLSN); err != nil { 45 | // log.Fatalf("Error incrementing LSN: %s", err) 46 | // } 47 | 48 | for { 49 | time.Sleep(3 * time.Second) 50 | 51 | // Get current max LSN so we have a moving upper bound 52 | if err := db.QueryRowContext(context.TODO(), "SELECT sys.fn_cdc_get_max_lsn()").Scan(&toLSN); err != nil { 53 | log.Fatalf("Error getting max LSN: %s", err) 54 | } 55 | if string(fromLSN) == string(toLSN) { 56 | fmt.Println("Reachd the end, waiting for change...") 57 | continue 58 | } 59 | 60 | q := fmt.Sprintf(`SELECT * FROM cdc.fn_cdc_get_all_changes_%s(@fromLSN, @toLSN, 'all')`, users.captureInstance) 61 | rows, err := db.QueryContext(context.TODO(), q, sql.Named("fromLSN", fromLSN), sql.Named("toLSN", toLSN)) 62 | if err != nil { 63 | log.Fatalf("Error querying changes: %s", err) 64 | } 65 | 66 | for rows.Next() { 67 | var ( 68 | lsn []byte 69 | seqval []byte 70 | op int 71 | mask []byte 72 | id int 73 | name string 74 | ) 75 | 76 | if err := rows.Scan(&lsn, &seqval, &op, &mask, &id, &name); err != nil { 77 | log.Printf("Failed to scan row: %s", err) 78 | continue 79 | } 80 | 81 | operation := map[int]string{ 82 | 1: "DELETE", 83 | 2: "INSERT", 84 | 3: "UPDATE (before)", 85 | 4: "UPDATE (after)", 86 | }[op] 87 | 88 | fmt.Printf("LSN: %x | Operation: %s | ID: %d | Name: %s\n", lsn, operation, id, name) 89 | fromLSN = lsn 90 | } 91 | rows.Close() 92 | } 93 | 94 | } 95 | 96 | func cdcEnabled(db *sql.DB) (map[string]*changeTable, error) { 97 | rows, err := db.Query("SELECT capture_instance, start_lsn, end_lsn FROM cdc.change_tables;") 98 | if err != nil { 99 | return nil, err 100 | } 101 | 102 | defer rows.Close() 103 | results := make(map[string]*changeTable) 104 | for rows.Next() { 105 | var ct changeTable 106 | if err := rows.Scan(&ct.captureInstance, &ct.startLsn, &ct.endLsn); err != nil { 107 | log.Printf("Failed to scan row: %s\n", err) 108 | continue 109 | } 110 | results[ct.captureInstance] = &ct 111 | } 112 | 113 | return results, nil 114 | } 115 | 116 | func printUsers(db *sql.DB) { 117 | query := `SELECT __$start_lsn, __$operation, id, name FROM cdc.dbo_users_CT ORDER BY __$start_lsn;` 118 | rows, err := db.Query(query) 119 | if err != nil { 120 | log.Fatalf("Query failed: %s", err) 121 | } 122 | defer rows.Close() 123 | 124 | for rows.Next() { 125 | var lsn []byte 126 | var op int 127 | var id int 128 | var name string 129 | 130 | if err := rows.Scan(&lsn, &op, &id, &name); err != nil { 131 | log.Printf("Failed to scan row: %s", err) 132 | continue 133 | } 134 | 135 | operation := map[int]string{ 136 | 1: "DELETE", 137 | 2: "INSERT", 138 | 3: "UPDATE (before)", 139 | 4: "UPDATE (after)", 140 | }[op] 141 | 142 | fmt.Printf("LSN: %x | Operation: %s | ID: %d | Name: %s\n", lsn, operation, id, name) 143 | } 144 | } 145 | 146 | // getMinLSN acts as a starting point for the first query 147 | func getMinLSN(db *sql.DB) ([]byte, error) { 148 | var minLSN []byte 149 | err := db.QueryRow("SELECT sys.fn_cdc_get_min_lsn('dbo_users')").Scan(&minLSN) 150 | if err != nil { 151 | return nil, fmt.Errorf("get min LSN: %w", err) 152 | } 153 | return minLSN, nil 154 | } 155 | 156 | func getMaxLSN(db *sql.DB) ([]byte, error) { 157 | var lsn []byte 158 | err := db.QueryRow("SELECT sys.fn_cdc_get_max_lsn()").Scan(&lsn) 159 | return lsn, err 160 | } 161 | --------------------------------------------------------------------------------