Hi Friends,
This is my 13th blog on SQL Server Trace Flag 1117 in the series of One Trace Flag a Day. You can go to all blogs under that series by clicking here.
Default Behavior: Consider that we have a database which has a default Primary data filegroup with four files inside that filegroup. Each data file has some initial size like 4 MB with 2 MB auto growth. During database uses sql server come across a situation where all data files are full right now i.e. all data files of size 4 MB are Full. Then auto growth event will fire and will increase the size for first data file by 2 MB as per auto growth setting. Now SQL Server will start to use this free space inside first data file, which is generated by auto growth.
Let me show you this default behavior practically:
USE [master] GO CREATE DATABASE [Test1117] ON PRIMARY ( NAME = N'Test1117_1', FILENAME = N'E:\DATA\Test1117_1.mdf' , SIZE = 4 MB , MAXSIZE = 512 MB, FILEGROWTH = 2 MB ), ( NAME = N'Test1117_2', FILENAME = N'E:\DATA\Test1117_2.ndf' , SIZE = 4 MB , MAXSIZE = 512 MB, FILEGROWTH = 2 MB ), ( NAME = N'Test1117_3', FILENAME = N'E:\DATA\Test1117_3.ndf' , SIZE = 4 MB , MAXSIZE = 512 MB, FILEGROWTH = 2 MB ), ( NAME = N'Test1117_4', FILENAME = N'E:\DATA\Test1117_4.ndf' , SIZE = 4 MB , MAXSIZE = 512 MB, FILEGROWTH = 2 MB ) LOG ON ( NAME = N'Test1117_log', FILENAME = N'E:\LOG\Test1117_log.ldf' , SIZE = 4096KB , MAXSIZE = 4096MB , FILEGROWTH = 4096KB ) GO use [Test1117] go create table xtTest1117 ( TestData char(8000) ) go Select name,(size*8)/1024 Size_MB from sys.database_files where type=0 go insert into xtTest1117 values('Welcome to SQLServerGeeks.com') go 1600 Select name,(size*8)/1024 Size_MB from sys.database_files where type=0 go --as of now all data files are almost full here. if i will insert more rows then autogrowth event will occur only for single file. insert into xtTest1117 values('Welcome to SQLServerGeeks.com') go 200 Select name,(size*8)/1024 Size_MB from sys.database_files where type=0 go
So from above output it is clear that under default behavior one file will grow at the time of auto grow event. Now let me show you the same code with trace flag 1117. Now if auto grow event will fire under a filegroup then all files under that filegroup will grow.
USE [master] GO DROP DATABASE [Test1117] GO CREATE DATABASE [Test1117] ON PRIMARY ( NAME = N'Test1117_1', FILENAME = N'E:\DATA\Test1117_1.mdf' , SIZE = 4 MB , MAXSIZE = 512 MB, FILEGROWTH = 2 MB ), ( NAME = N'Test1117_2', FILENAME = N'E:\DATA\Test1117_2.ndf' , SIZE = 4 MB , MAXSIZE = 512 MB, FILEGROWTH = 2 MB ), ( NAME = N'Test1117_3', FILENAME = N'E:\DATA\Test1117_3.ndf' , SIZE = 4 MB , MAXSIZE = 512 MB, FILEGROWTH = 2 MB ), ( NAME = N'Test1117_4', FILENAME = N'E:\DATA\Test1117_4.ndf' , SIZE = 4 MB , MAXSIZE = 512 MB, FILEGROWTH = 2 MB ) LOG ON ( NAME = N'Test1117_log', FILENAME = N'E:\LOG\Test1117_log.ldf' , SIZE = 4096KB , MAXSIZE = 4096MB , FILEGROWTH = 4096KB ) GO use [Test1117] go create table xtTest1117 ( TestData char(8000) ) go Select name,(size*8)/1024 Size_MB from sys.database_files where type=0 go DBCC TRACEON(1117,-1) go insert into xtTest1117 values('Welcome to SQLServerGeeks.com') go 1600 Select name,(size*8)/1024 Size_MB from sys.database_files where type=0 go --as of now all data files are almost full here. if i will insert more rows then auto growth event will occur for all data files. go insert into xtTest1117 values('Welcome to SQLServerGeeks.com') go 200 Select name,(size*8)/1024 Size_MB from sys.database_files where type=0 go go DBCC TRACEOFF(1117,-1) Go
PS: Do not use trace flags in production environment without testing it on non production environments and without consulting because everything comes at a cost.
HAPPY LEARNING!
Regards:
Prince Kumar Rastogi
Like us on FaceBook | Join the fastest growing SQL Server group on FaceBook
Follow Prince Rastogi on Twitter | Follow Prince Rastogi on FaceBook
Hi Prince,
But what is the actual advantage to the files growing at equal rates?