Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase ««12

Transaction log SHRINK Expand / Collapse
Author
Message
Posted Saturday, January 12, 2013 11:18 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 4:41 AM
Points: 42,814, Visits: 35,937
muthukkumaran Kaliyamoorthy (1/12/2013)
Have a look Truncating and shrinking the transaction log file

Also take a look @ http://www.sqlserverblogforum.com/2011/06/sql-server-recovery-models-and-backup-types/


There's a bunch of errors in both of those, just beware (but that should apply to just about anything you read on the net)



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1406396
Posted Saturday, January 12, 2013 6:20 PM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, August 12, 2014 3:57 PM
Points: 369, Visits: 1,211
There's no implicit (or explicit) checkpoint that happens within the transaction log backup

I know for sure (tested and double-checked) that checkpoint is implicitly executed at the beginning of full or diff backup process, but I did not know that it is not implicitly executed at transaction log backup.
And that makes sense when I think about that processes.
Thanks Gail, I have learned something today. It's so good to help people and learn something in the process.

in full recovery checkpoint won't do anything to the log. Only a log backup clears the log in full recovery.

Checkpoint writes to the log: checkpoint begin, checkpoint end, and list of active transactions' LSNs.
But there is one more thing that checkpoint does to the log in regard of log truncation.
Checkpoint is one of several prerequisites for log clearing. Log backup triggers that clearing, but will VLF's actually be cleared (if any at all) is determined by several prerequisites. And checkpoint is one of those prerequisites! That's why "CHECKPOINT" is listed under possible values of log_reuse_wait_desc in sys.databases: http://msdn.microsoft.com/en-us/library/ms178534.aspx, and that reason can happen in full recovery model also.
Log records after the last checkpoint are badly needed by someone: by the recovery process.
See here (BOL): http://msdn.microsoft.com/en-us/library/ms189085%28v=sql.105%29.aspx

If disaster strikes, recovery process begins at the point of the last checkpoint in transaction log (page 1:9 contains that log location, and minLSN which might be prior or equal to checkpoint). Because checkpoint is a "firm point" - the actual state of data files we have on disks. Always from that point (from that checkpoint) it rolls forward the entire log, and then rolls back transactions that were active (uncommitted) at the moment of disaster. So, it needs AT LEAST the log from the last checkpoint and on (I say "at least" because active transactions can make that range even wider if they start before last checkpoint, and minLSN can be even before that checkpoint, but never after that last checkpoint). That means you can't clear the VLFs starting with the one that contains the last checkpoint and on, no matter how many times you call "backup log" command, and even if you don't have any opened transactions.

Basically, with CHECKPOINT command just prior to shrink log you may achieve a little bit more of log cleared (and thus shrinked) than without it.
Though, the difference is probably not huge because checkpoints happen automatically quite often (roughly once per minute, depending on "recovery interval" setting, log record generation rate, and few other factors), enabling you to clear the log with log backup.


_____________________________________________________
Microsoft Certified Master: SQL Server 2008
XDetails Addin - for SQL Developers
blog.sqlxdetails.com - Transaction log myths
Post #1406436
Posted Saturday, January 12, 2013 7:07 PM


Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: 2 days ago @ 12:38 PM
Points: 1,155, Visits: 4,640
GilaMonster (1/12/2013)
muthukkumaran Kaliyamoorthy (1/12/2013)
Have a look Truncating and shrinking the transaction log file

Also take a look @ http://www.sqlserverblogforum.com/2011/06/sql-server-recovery-models-and-backup-types/


There's a bunch of errors in both of those, just beware (but that should apply to just about anything you read on the net)


I'll take a look and correct those. Thanks Gail.


Muthukkumaran Kaliyamoorthy

Helping SQL DBAs and Developers >>>SqlserverBlogForum
Post #1406441
Posted Sunday, January 13, 2013 1:09 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 4:41 AM
Points: 42,814, Visits: 35,937
Vedran Kesegic (1/12/2013)
But there is one more thing that checkpoint does to the log in regard of log truncation.
Checkpoint is one of several prerequisites for log clearing.


Yes, I'm well aware of what checkpoint does.

Log backup triggers that clearing, but will VLF's actually be cleared (if any at all) is determined by several prerequisites. And checkpoint is one of those prerequisites!


Correct it is (and since I wrote an article on that subject, I'm kinda familiar with the reasons why the log may not be reused)

Basically, with CHECKPOINT command just prior to shrink log you may achieve a little bit more of log cleared (and thus shrinked) than without it.


Not in full or bulk-logged recovery. In simple recovery Checkpoint triggers log clearing, so your statement is true for simple recovery. In full recovery, only a log backup triggers log clearing (checkpoint does not). Hence, if at the point that you run a log backup, there are log records that are required for a checkpoint, the VLFs with those log records will not be cleared. If you then run a checkpoint, those log records are no longer needed, but the log clearing (to clear those now clearable VLFs) will not run until another log backup is run.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1406456
Posted Sunday, January 13, 2013 7:18 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, August 12, 2014 3:57 PM
Points: 369, Visits: 1,211
I'm well aware what triggers log truncation in simple vs full/bulk recovery model (checkpoint vs log backup). I'm also aware of the conditions that determine what VLFs will actually be cleared (if any at all), once the clearing process is triggered. Those clearing conditions are also different, depending on recovery model, is there mirroring, transaction replication, full/diff bacup in progress etc.
Checkpoint does not require any log records - crash recovery process does. But the checkpoint (better to say: the lack of it) can prevent VLF to be cleared (when clearing process is triggered by log backup).


_____________________________________________________
Microsoft Certified Master: SQL Server 2008
XDetails Addin - for SQL Developers
blog.sqlxdetails.com - Transaction log myths
Post #1406462
Posted Sunday, January 13, 2013 7:22 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, August 12, 2014 3:57 PM
Points: 369, Visits: 1,211
I tried to setup excercise in full recovery model that shows in log truncation that occured no VLF's are marked inactive because the lack of the CHECKPOINT.
But, it turns out that checkpoint indeed occurs even at the beginning of a log backup,
not just full/diff backup. At least in SQL2012 instance i tried that.
Here it is, try it:

-- We will prevent file growth by setting maxsize equal to initial size
create database TestCKPT ON
PRIMARY
( NAME = data,
FILENAME = 'D:\temp\TestCKPT.mdf',
SIZE = 100 MB,
MAXSIZE = 100 MB
)
LOG ON
( NAME = log,
FILENAME = 'D:\temp\TestCKPT.ldf',
SIZE = 65544 KB, -- 64MB + 1 page
MAXSIZE = 65544 KB
)
GO

-- We wont to control when checkpoint occur. So, we will disable automatic checkpoins by trace flag 3505
-- to prevent automatic checkpoint occur for duration of the test.
-- Alternative would be increasing the RECOVERY INTERVAL parameter.
EXEC sp_configure 'show advanced options', 1
GO
RECONFIGURE
GO
EXEC sp_configure 'recovery interval', 32767
GO
RECONFIGURE WITH OVERRIDE
GO
ALTER DATABASE TestCKPT SET TARGET_RECOVERY_TIME = 3600 MINUTES
GO

-- Pu full recovery model in effect
USE TestCKPT
alter database TestCKPT SET recovery FULL
-- Until we take a full backup, we are effectively in SIMPLE recovery model,
-- even if sys.databases shows it is in FULL.
-- So let's take a full backup to kick-start full rm:
BACKUP DATABASE TestCKPT TO DISK = 'D:\temp\TestCKPT.bak'
backup log TestCKPT TO DISK = 'TestCKPT.ldf'
GO




-- Checkpoint location is in VLF that is first part of three-part LSN.
-- That is 21 in our case:
SELECT
DB_NAME() AS DatabaseName
, [Current LSN]
, [Previous LSN]
, Operation
, [Checkpoint Begin]
, [Checkpoint End]
, [Dirty Pages]
FROM fn_dblog(NULL, NULL)
WHERE operation IN ( 'LOP_BEGIN_CKPT', 'LOP_END_CKPT')

-- This is a list of all VLF's (one row equals one VLF).
-- We can see that active VLF is the one with VLF seqence number 21 (the one that checkpoint is)
declare @vlfs table
( RecoveryUnitId int, -- sql2012 only
FileId int,
FileSize bigint, -- VLF size in bytes
StartOffset bigint, -- VLF offset in bytes from beginning of transaction log
FSeqNo int,
Status int,
Parity tinyint,
CreateLSN decimal(25,0)
)
insert into @vlfs
exec('DBCC LOGINFO () WITH TABLERESULTS, NO_INFOMSGS')
SELECT
VLF_SeqNo = convert(varbinary(4),v.FSeqNo),
file_id = v.FileId, logical_name = f.name, f.physical_name, log_size_kb = REPLACE(CONVERT(varchar, f.size*$8, 1), '.00', ''),
vlf_size_kb = REPLACE(CONVERT(varchar, v.FileSize/$1024, 1), '.00', ''),
vlf_physical_offset = v.StartOffset,
WriteSequenceNo = ROW_NUMBER() OVER(ORDER BY v.FSeqNo),
Status = CASE WHEN v.Status=2 THEN 'ACTIVE' ELSE 'INACTIVE (free)' END,
v.CreateLSN
FROM @vlfs v
JOIN sys.database_files f on f.file_id = v.FileId
order by v.StartOffset
GO

-- Let's make some transaction to move log insertion point to the next VLF
CREATE TABLE wide(x nchar(4000) DEFAULT 'A') -- a bit less than 8KB, one page
GO
INSERT INTO wide default values
GO 1024

-- By running previous queries, confirm that we have moved to the next VLF (22) - now we have two active VLFs
-- and confirm that no checkpoint has occured other than the one we saw in previous VLF (21).


-- We dont have any open transactions. Will log backup mark the first VLF inactive (clear it) ?
SELECT
DB_NAME() AS DatabaseName
, [Current LSN]
, [Previous LSN]
, Operation
, [Checkpoint Begin]
, [Checkpoint End]
, [Dirty Pages]
FROM fn_dblog(NULL, NULL)
WHERE operation IN ( 'LOP_BEGIN_CKPT', 'LOP_END_CKPT')
backup log TestCKPT TO DISK = 'TestCKPT2.ldf'
SELECT
DB_NAME() AS DatabaseName
, [Current LSN]
, [Previous LSN]
, Operation
, [Checkpoint Begin]
, [Checkpoint End]
, [Dirty Pages]
FROM fn_dblog(NULL, NULL)
WHERE operation IN ( 'LOP_BEGIN_CKPT', 'LOP_END_CKPT')

-- TURNS OUT CHECKPOINT OCCURED ON TRAN LOG BACKUP!

-- cleanup
use master
drop database TestCKPT
GO



_____________________________________________________
Microsoft Certified Master: SQL Server 2008
XDetails Addin - for SQL Developers
blog.sqlxdetails.com - Transaction log myths
Post #1406463
Posted Sunday, January 13, 2013 9:38 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 4:41 AM
Points: 42,814, Visits: 35,937
Vedran Kesegic (1/13/2013)
But, it turns out that checkpoint indeed occurs even at the beginning of a log backup, not just full/diff backup.


It can occur. It's not an automatic thing that always happens, but it can (I've seen checkpoints triggered by a log backup when either traceflags or server settings have resulted in a lack of automatic checkpoints).

But the checkpoint (better to say: the lack of it) can prevent VLF to be cleared (when clearing process is triggered by log backup).


Of course it can.
What I'm saying, and have been saying, is that a checkpoint after a log backup will not mark additional log records as reusable and hence will not allow a shrink to reclaim more space than it would if the checkpoint had not been run after the log backup.



Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1406475
Posted Sunday, January 13, 2013 11:00 AM


Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Tuesday, August 12, 2014 3:57 PM
Points: 369, Visits: 1,211
a checkpoint after a log backup will not mark additional log records as reusable and hence will not allow a shrink to reclaim more space than it would if the checkpoint had not been run after the log backup.


Totally agree.
So, the order would be:

1) checkpoint
2) BACKUP LOG MYDatabase TO DISK='D:\transactionLogBackup1.trn'
3) DBCC SHRINKFILE('MyTransactionLogName', 1000) -- 1000 MB. Set as you like.
Repeat 1-3 until shrinked


_____________________________________________________
Microsoft Certified Master: SQL Server 2008
XDetails Addin - for SQL Developers
blog.sqlxdetails.com - Transaction log myths
Post #1406496
Posted Sunday, January 13, 2013 12:54 PM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 4:41 AM
Points: 42,814, Visits: 35,937
That would work better than the order you originally had, yes.


Gail Shaw
Microsoft Certified Master: SQL Server 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1406504
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse