SQL Server Transaction Marks: Restoring multiple databases to a common relative point
- by Mladen Prajdic
We’re all familiar with the ability to restore a database to point in time using the RESTORE WITH STOPAT statement. 
But what if we have multiple databases that are accessed from one application or are modifying each other? And over multiple instances? And all databases have different workloads? And we want to restore all of the databases to some known common relative point? The catch here is that this common relative point isn’t the same point in time for all databases. This common relative point in time might be now in DB1, now-1 hour in DB2 and yesterday in DB3. And we don’t know the exact times.
Let me introduce you to Transaction Marks. When we run a marked transaction using the WITH MARK option a flag is set in the transaction log and a row is added to msdb..logmarkhistory table. When restoring a transaction log backup we can restore to either before or after that marked transaction. The best thing is that we don’t even need to have one database modifying another database. All we have to do is use a marked transaction with the same name in different database.
Let’s see how this works with an example. The code comments say what’s going on.
    
        
            
            
            USE master GOCREATE DATABASE TestTxMark1GOUSE TestTxMark1GOCREATE TABLE TestTable1(    ID INT,    VALUE UNIQUEIDENTIFIER)
            
            
            -- insert some data into the table so we can have a starting pointINSERT INTO TestTable1SELECT  ROW_NUMBER() OVER(ORDER BY number) AS RN, NULLFROM    master..spt_valuesORDER BY RNSELECT  *FROM    TestTable1GO-- TAKE A FULL BACKUP of the databseBACKUP DATABASE TestTxMark1 TO DISK = 'c:\TestTxMark1.bak'GO
            
            
            
            
            
            
            
            USE master GOCREATE DATABASE TestTxMark2GOUSE TestTxMark2GOCREATE TABLE TestTable2(    ID INT,    VALUE UNIQUEIDENTIFIER)-- insert some data into the table so we can have a starting pointINSERT INTO TestTable2SELECT  ROW_NUMBER() OVER(ORDER BY number) AS RN, NEWID()FROM    master..spt_valuesORDER BY RNSELECT  *FROM    TestTable2GO-- TAKE A FULL BACKUP of our databseBACKUP DATABASE TestTxMark2 TO DISK = 'c:\TestTxMark2.bak'GO
            
            
            
        
        
            
            
            -- start a marked transaction that modifies both databasesBEGIN TRAN TxDb WITH MARK    -- update values from NULL to random value    UPDATE TestTable1    SET VALUE = NEWID();    -- update first 100 values from random value 
                -- to NULL in different DB    UPDATE TestTxMark2.dbo.TestTable2    SET VALUE = NULL    WHERE ID <= 100;COMMITGO
            
            
            
            
             
             
            
            -- some time goes by here -- with various database activity...
            
            
            
        
        
            
            
            -- We see two entries for marks in each database. -- This is just informational and has no bearing on the restore itself.SELECT * FROM msdb..logmarkhistory
            
            
             
        
        
            
            USE masterGO-- create a log backup to restore to mark pointBACKUP LOG TestTxMark1 TO DISK = 'c:\TestTxMark1.trn'GO-- drop the database so we can restore it backDROP DATABASE TestTxMark1GO
            
            
            
            USE masterGO-- create a log backup to restore to mark pointBACKUP LOG TestTxMark2 TO DISK = 'c:\TestTxMark2.trn'GO-- drop the database so we can restore it backDROP DATABASE TestTxMark2GO
            
            
        
        
            
            
            -- RESTORE THE DATABASE BACK BEFORE OUR TRANSACTION-- restore the full backup RESTORE DATABASE TestTxMark1    FROM DISK = 'c:\TestTxMark1.bak'       WITH NORECOVERY;-- restore the log backup to the transaction markRESTORE LOG TestTxMark1 FROM DISK = 'c:\TestTxMark1.trn'    WITH RECOVERY,          -- recover to state before the transaction         STOPBEFOREMARK  = 'TxDb';         -- recover to state after the transaction         -- STOPATMARK = 'TxDb';GO
            
            
            
            
            -- RESTORE THE DATABASE BACK BEFORE OUR TRANSACTION-- restore the full backup RESTORE DATABASE TestTxMark2    FROM DISK = 'c:\TestTxMark2.bak'    WITH NORECOVERY;-- restore the log backup to the transaction markRESTORE LOG TestTxMark2 FROM DISK = 'c:\TestTxMark2.trn'    WITH RECOVERY,          -- recover to state before the transaction         STOPBEFOREMARK  = 'TxDb';         -- recover to state after the transaction         -- STOPATMARK = 'TxDb';GO
            
            
        
        
            
            
            USE TestTxMark1-- we restored to time before the transaction -- so we have NULL values in our tableSELECT * FROM TestTable1
            
            
            
            
            USE TestTxMark2-- we restored to time before the transaction -- so we DON'T have NULL values in our tableSELECT * FROM TestTable2
            
            
        
    
 
Transaction marks can be used like a crude sync mechanism for cross database operations. With them we can mark our databases with a common “restore to” point so we know we have a valid state between all databases to restore to.