Subtle change to ::fn_dblog in SQL 2008
Bizarrely given that transaction log decoding is not really viable as a technique beyond interest, it’s quite surprising how many people visit just to understand or learn how to do it. Either a lot of data is being lost and no backup’s exist – or it fascinates a large number of people.
In either instance, there are sometimes subtle changes can pass you by, and the use of old habits can make life a bit harder. One such recent change that I missed was an alteration to the ::fn_dblog function. I really should have spent some time investigating the new fields that had been added – but with documentation being limited to say the least, it has not been the top priority and my habit is to fire up SQL 2005 when checking something in the transaction log – so I had not noticed them.
One of the changes is the creation of a link between the contents of sys.dm_tran_current_transaction and the transaction log itself. The contents of the view have not altered, but one of the new fields within the output from ::fn_fblog is a new field called Xact_ID – this field contains the same value as the Transaction_ID that is output from the DMV.
Now that is significantly convenient for when you’re poking around in logs trying to understand cause and effect .
A couple of simple stored procedures later to assist in saving and returning that filtered information as follows:
CREATE PROCEDURE sp_store_transaction <AS BEGIN DECLARE @dm_transaction_id bigint SELECT @dm_transaction_id = transaction_id FROM sys.dm_tran_current_transaction IF OBJECT_ID (N'tempdb.dbo.##db_last_transaction') IS NOT NULL DROP TABLE ##db_last_transaction SELECT [transaction id] INTO ##db_last_transaction FROM ::fn_dblog(null,null) WHERE [Xact ID] = @dm_transaction_id <END GO
CREATE PROCEDURE sp_get_last_transaction AS BEGIN SELECT * FROM ::fn_dblog(null,null) WHERE [Transaction ID] = (SELECT [transaction id] FROM ##db_last_transaction) END GO
And that is going to make looking at cause an effect far easier – first procedure you call anywhere within your transaction to store the current transaction_id within the log, and the second to retrieve the values for that stored transaction id. Something like:
BEGIN TRAN UPDATE tbltest SET firstname = 'ab' EXEC sp_store_transaction COMMIT TRAN sp_get_last_transaction
If you are wondering why I did not dump the log records out and only the transaction id that ties them together – if you dumped the records before the transaction committed or rolled back, you would not see the effect of that action – you need to retrieve all the log rows associated to that transaction, after it has finished.
To satisfy your curiosity regarding the question “Why would there is so much interest”. We are looking into this for the possibility of incremental data captures. Sure, you have replication, DML triggers and Change Data Capture. However, this is a vendor supplied database. By contract, if we make ANY change to the database (even non-destructive changes) they cancel our 5 year support contract. All of the methods I mention above modify the database in some way… and, yes, the vendor states that marking the table as a ‘publisher’ for replication is in volation. Sad but true