Blog Post

A Busy/Accidental DBA’s Guide to Managing VLFs

,

Introduction

Properly managing VLFs can make or break the performance of your databases. There is a ton of information out there on the proper management of VLFs, but nothing I have found that tries to boil it down to the most important parts. So here it is, my attempt at A Busy/Accidental DBA’s Guide to Managing VLFs.

What are VLFs?

When SQL Server allocates new space in a log file it does it using Virtual Log Files (VLFs), meaning every growth of a transaction log file is made of 4 or more VLFs.  Think of VLFs as small files within the file that are easier for SQL Server to manage than one large file. (There really is a lot more to it than that but rather than lift from BOL I will refer you to this page for a more detailed explanation.)

Why Manage VLFs?

Having too many or in some cases not enough VLFs can cause sluggish database performance. I have also heard cases of database recovery taking far longer than expected when a log file contains too many VLFs.

How Many VLFs Should I have?

To quote someone much wiser: “It depends”. I use 50 VLFs as my rule of thumb because it is much easier to have a simple rule and it is a safe number in most cases. I do suggest reading this article: Transaction Log VLFs – too many or too few? before committing to a number of your own, especially if you are working with VLDBs.

How do I Manage VLFs?

Managing VLFs is a 2 step process. Step 1 is figuring out how many VLFs you have in each of your transaction logs. Step 2 is deciding on what number of VLFs is acceptable to you and shrinking and growing the log files to get them back under your threshold.  I have included scripts below that will help you identify and remediate high VLF counts. They probably could be wrapped up into a single script but I prefer to have control of what is running when so I can monitor for any issues the maintenance might cause.

Many people also add a step 3 where they increase the auto-growth increment of their database. I tend to avoid raising the auto-growth unless the database is new. The log should only grow very rarely on a mature database; constantly having to address VLFs in a particular database’s log could be a sign of a larger problem like auto-shrink being turned on.

What if I Just Shrink the Log and Let it Grow Back?

There is a misconception that shrinking a log and increasing the auto-growth is enough to remediate high VLF counts. While shrinking a log file may lower VLF counts temporarily, they will come right back when the log file grows back. This article: Transaction Log VLFs – too many or too few? lays out how many VLFs will be added based on the auto-growth increment.  Rephrased from the article:

  •       If the file growth is less than 64MB the new portion of the log file will contain 4 VLFs
  •       If the file growth is at least 64MB and less than 1GB the new portion of the log file will contain 8 VLFs
  •       If the file growth is at least 1GB and larger = 16VLFs

Based on that, if an 80GB log with 100 VLFs was shrunk to remove VLFs then allowed to auto-grow back to 80GB with a larger auto-growth increment, say 4GB, the log would contain 20*16 = 320 VLFs.

How Many VLFs are in My Databases?

This script will return the VLF count for each database on the server it is run on. I am not sure of the origins of the script but I can say it works for me.  If you know or are the original author of this script please let me know so I can give proper credit or replace the script with a link to a more current version.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
DECLARE @query varchar(1000),

@dbname varchar(1000),

@count int

SET NOCOUNT ON

DECLARE csr CURSOR FAST_FORWARD READ_ONLY

FOR

SELECT name

FROM master.dbo.sysdatabases

CREATE TABLE ##loginfo

(

dbname varchar(100),

num_of_rows int)

OPEN csr

FETCH NEXT FROM csr INTO @dbname

WHILE (@@fetch_status <> -1)

BEGIN

CREATE TABLE #log_info

(

fileid tinyint,

file_size bigint,

start_offset bigint,

FSeqNo int,

[status] tinyint,

parity tinyint,

create_lsn numeric(25,0)

)

SET @query = 'DBCC loginfo (' + '''' + @dbname + ''') '

INSERT INTO #log_info

EXEC (@query)

SET @count = @@rowcount

DROP TABLE #log_info

INSERT ##loginfo

VALUES(@dbname, @count)

FETCH NEXT FROM csr INTO @dbname

END

CLOSE csr

DEALLOCATE csr

SELECT dbname,

num_of_rows

FROM ##loginfo

WHERE num_of_rows >= 50 --My rule of thumb is 50 VLFs. Your mileage may vary.

ORDER BY dbname

DROP TABLE ##loginfo

 

How Do I Lower a Database’s VLF Count?

Once armed with a list of databases that have high VLF counts, the next step is to shrink the logs to as small as possible then grow them back to the original size, ideally in a single growth. This is best done during off-peak times. I wrote the following script to perform those exact steps given the appropriate USE statement. You may have to run it multiple times to get to a low enough VLF count.

 

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
/*USE <>*/ --Set db name before running using drop-down above or this USE statement

DECLARE @file_name sysname,

@file_size int,

@file_growth int,

@shrink_command nvarchar(max),

@alter_command nvarchar(max)

SELECT @file_name = name,

@file_size = (size / 128),

@file_growth = CASE

WHEN (growth / 128) < 100

THEN 100

WHEN (growth / 128) < 250

THEN 250

WHEN (growth / 128) < 500

THEN 500

ELSE 1000

END

FROM sys.database_files

WHERE type_desc = 'log'

SELECT @shrink_command = 'DBCC SHRINKFILE (N''' + @file_name + ''' , 0, TRUNCATEONLY)'

PRINT @shrink_command

EXEC sp_executesql @shrink_command

SELECT @shrink_command = 'DBCC SHRINKFILE (N''' + @file_name + ''' , 0)'

PRINT @shrink_command

EXEC sp_executesql @shrink_command

SELECT @alter_command = 'ALTER DATABASE [' + db_name() + '] MODIFY FILE (NAME = N''' + @file_name + ''', SIZE = ' + CAST(@file_size AS nvarchar) + 'MB)'

PRINT @alter_command

EXEC sp_executesql @alter_command

In Closing

This has by no means a comprehensive lesson in VLFs or transaction log management, but hopefully enough to get the job done. If you are looking for a more in-depth look at VLFs and transaction logs in general I suggest reading the following articles: Understanding Logging and Recovery in SQL Server, Transaction Log VLFs – too many or too few? and 8 Steps to better Transaction Log throughput.

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating