SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Field Level Auditing using Change Data Capture – Part 2


Field Level Auditing using Change Data Capture – Part 2

Author
Message
David Balthrop
David Balthrop
Valued Member
Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)

Group: General Forum Members
Points: 54 Visits: 55
Comments posted to this topic are about the item Field Level Auditing using Change Data Capture – Part 2
TheSpyder
TheSpyder
SSC Rookie
SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)SSC Rookie (26 reputation)

Group: General Forum Members
Points: 26 Visits: 45
What could be better you ask. How about doing it all in the database and leaving out he SSIS stuff. I had an occasion in the old 2000 days when I needed to move to a new server. The database was no problem but we had loads of DTS jobs to maintain the Disaster Recovery and Data Warehouse. That was a nightmare. Since then, I've tried to do everything with stored procedures and SQL Agent jobs which makes moving from one server to another a doddle.

Perhaps SSIS is easier to move than DTS? I have yet to get my fingers dirty with it. I'd be interested in your comments.
David Balthrop
David Balthrop
Valued Member
Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)

Group: General Forum Members
Points: 54 Visits: 55
Unless the database table structures are changing, switching an SSIS job from one server to another is pretty straight forward. The configuration information for the database connections should be stored either in a config file or in a database, simiply change that connection information to point at the new server.

If the table structures are changing, CDC does not handle that automagically. See the posts on Part 1 article on example of how to update CDC with DDL changes.

CDC does have it's draw backs, to track who is making the changes you have to add user information to your tables and change the data access to save that data. Some people may not need that level of control. But if you are working on aa application that shullfes billions of dollars a year, it is pretty important to be able to answer "who made that change"?

But beyond auditing, there are other uses for CDC like ETL processing for delta updates, load use reports, etc. Still say it's cool.
tutupouet
tutupouet
SSC Veteran
SSC Veteran (202 reputation)SSC Veteran (202 reputation)SSC Veteran (202 reputation)SSC Veteran (202 reputation)SSC Veteran (202 reputation)SSC Veteran (202 reputation)SSC Veteran (202 reputation)SSC Veteran (202 reputation)

Group: General Forum Members
Points: 202 Visits: 278
There is an error in [CDCDemo].[dbo].[spgGetCDCContract]
replace
SET @from_lsn = sys.fn_cdc_map_time_to_lsn('largest greater than', @FromLSNDate);


by
SET @from_lsn = sys.fn_cdc_map_time_to_lsn('smallest greater than', @FromLSNDate);


e.t.anicet
e.t.anicet
SSC Rookie
SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)

Group: General Forum Members
Points: 37 Visits: 100
Hi David

I did try several times your demonstration but I couldn't get the stagingCdcContract Table populate with data.
When I run the stored procedure "Exec [dbo].[sPgGetCDCContract] @FromLSNDate=?, @ToLSNDate=?" I get an empty table in return, So I don't know whether I have done something wrong or the stored procedure has an mistake.
Here is the [sPgGetCDCContract] code:

USE [CDCDemo]
GO

/****** Object: StoredProcedure [dbo].[sPgGetCDCContract] Script Date: 11/12/2011 15:43:18 ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO


CREATE PROCEDURE [dbo].[sPgGetCDCContract]
@FromLSNDate as datetime,
@ToLSNDate as datetime
AS
begin
SET NOCOUNT ON
SET ROWCOUNT 0
declare @from_lsn binary(10)
declare @to_lsn binary(10)

SET @from_lsn = sys.fn_cdc_map_time_to_lsn('smallest greater than', @FromLSNDate);
SET @to_lsn = sys.fn_cdc_map_time_to_lsn('largest less than or equal', @ToLSNDate);
if (@from_lsn is not null and @to_lsn is not null and @from_lsn < @to_lsn)
begin
DECLARE @name_ordinal int
DECLARE @year_ordinal int
DECLARE @length_ordinal int
DECLARE @type_ordinal int
DECLARE @amount_ordinal int
DECLARE @last_change_id_ordinal int

SET @name_ordinal = sys.fn_cdc_get_column_ordinal('dbo_contract','name')
SET @year_ordinal = sys.fn_cdc_get_column_ordinal('dbo_contract','year')
SET @length_ordinal = sys.fn_cdc_get_column_ordinal('dbo_contract','length')
SET @type_ordinal = sys.fn_cdc_get_column_ordinal('dbo_contract','type')
SET @amount_ordinal = sys.fn_cdc_get_column_ordinal('dbo_contract','amount')
SET @last_change_id_ordinal = sys.fn_cdc_get_column_ordinal('dbo_contract','last_change_id')

SELECT cdc.fn_cdc_get_all_changes_dbo_contract.*,
sys.fn_cdc_map_lsn_to_time(__$start_lsn) as 'last_change_date',
cast(isnull(user_name, '') as varchar(100)) as 'last_change_name',
sys.fn_cdc_is_bit_set(@name_ordinal,__$update_mask) as 'IsNameUpdated',
sys.fn_cdc_is_bit_set(@year_ordinal,__$update_mask) as 'IsYearUpdated',
sys.fn_cdc_is_bit_set(@length_ordinal,__$update_mask) as 'IsLengthUpdated',
sys.fn_cdc_is_bit_set(@type_ordinal,__$update_mask) as 'IsTypeUpdated',
sys.fn_cdc_is_bit_set(@amount_ordinal,__$update_mask) as 'IsAmountUpdated',
sys.fn_cdc_is_bit_set(@last_change_id_ordinal,__$update_mask) as 'IsLastChangeIdUpdated'
FROM cdc.fn_cdc_get_all_changes_dbo_contract( @from_lsn, @to_lsn, 'all')
left join Users
on Users.user_id = fn_cdc_get_all_changes_dbo_contract.last_change_id
end
else
begin
-- return empty row
select cdc.dbo_contract_CT.*,
getdate() as 'last_change_date',
'' as 'last_change_name',
cast(0 as bit) as 'IsNameUpdated',
cast(0 as bit) as 'IsYearUpdated',
cast(0 as bit) as 'IsLengthUpdated',
cast(0 as bit) as 'IsTypeUpdated',
cast(0 as bit) as 'IsAmountUpdated',
cast(0 as bit) as 'IsLastChangeIdUpdated'
from cdc.dbo_contract_CT
where __$start_lsn = 0x00000000000000000000
end
end


GO

Thanks
David Balthrop
David Balthrop
Valued Member
Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)

Group: General Forum Members
Points: 54 Visits: 55
Am gussing it has something to do with the From or To LSN values, do you get any data back if you run this query directly against the CDCDemo database, this should verify that the change table is returning data:

DECLARE @from_lsn binary(10), @to_lsn binary(10)
SET @from_lsn =
sys.fn_cdc_get_min_lsn('dbo_contract')
SET @to_lsn = sys.fn_cdc_get_max_lsn()
SELECT * FROM cdc.fn_cdc_get_all_changes_dbo_contract( @from_lsn, @to_lsn, 'all')
GO
e.t.anicet
e.t.anicet
SSC Rookie
SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)

Group: General Forum Members
Points: 37 Visits: 100
Hi David,

Thanks to reply, yes I get data back when I run this last query against CDCDemo database:

DECLARE @from_lsn binary(10), @to_lsn binary(10)
SET @from_lsn =
sys.fn_cdc_get_min_lsn('dbo_contract')
SET @to_lsn = sys.fn_cdc_get_max_lsn()
SELECT * FROM cdc.fn_cdc_get_all_changes_dbo_contract( @from_lsn, @to_lsn, 'all')
GO
David Balthrop
David Balthrop
Valued Member
Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)Valued Member (54 reputation)

Group: General Forum Members
Points: 54 Visits: 55
ok, that's good. Let's try this next to see if the stored procedure can be run by itself.

-- get the @FromLSNDate date
use [CDCDW]
go
exec [spgGetCDCHistoryLastLSNDate] @cdcTable='dbo_contract'
go

-- get the @ToLSNDate date
use [CDCDemo]
go
exec [spgGetCDCMaxLSNDate]
go

-- substitute the dates returned above here and see if this returns results
exec [spgGetCDCContract] @FromLSNDate='2011-09-01 14:08:45.000', @ToLSNDate='2011-10-17 15:46:02.013'
e.t.anicet
e.t.anicet
SSC Rookie
SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)

Group: General Forum Members
Points: 37 Visits: 100
When I try this:

-- get the @FromLSNDate date
use [CDCDW]
go
exec [spgGetCDCHistoryLastLSNDate] @cdcTable='dbo_contract'
go

-- get the @ToLSNDate date
use [CDCDemo]
go
exec [spgGetCDCMaxLSNDate]
go

-- substitute the dates returned above here and see if this returns results
exec [spgGetCDCContract] @FromLSNDate='2011-11-15 09:18:39.000', @ToLSNDate='2011-11-15 09:23:40.700'

I still get no data back!
e.t.anicet
e.t.anicet
SSC Rookie
SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)SSC Rookie (37 reputation)

Group: General Forum Members
Points: 37 Visits: 100
Hi David,

have you still investigate in that stored procedure: "spgGetCDCContract", why I could not get data back when I try what you asked me to do?
Thanks
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search