SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 

The default filegroup, and why you should care.

You know you can have multiple filegroups right? You might have a separate filegroup for the data (the clustered index & heaps) and another for the indexes (non-clustered indexes). Or maybe you want to separate your data tables from the system tables. There are any number of reasons why you might want to have multiple filegroups, however, there will always be a primary filegroup and it will always be the default if you don’t specify otherwise. Right? Wrong.

I’ve never seen a way to remove primary or to move the system objects in it. However, you can change the primary filegroup.

CREATE DATABASE [PrimaryFG]
 ON  PRIMARY 
( NAME = N'PrimaryFG', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL13.SQL2016CS\MSSQL\DATA\PrimaryFG.mdf' , SIZE = 1048576KB , FILEGROWTH = 524288KB ), 
-- Create an additional filegroup and file for it.
 FILEGROUP [DATA] 
( NAME = N'PrimaryFG_Data', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL13.SQL2016CS\MSSQL\DATA\PrimaryFG_Data.ndf' , SIZE = 1048576KB , FILEGROWTH = 524288KB )
 LOG ON 
( NAME = N'PrimaryFG_log', FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL13.SQL2016CS\MSSQL\DATA\PrimaryFG_log.ldf' , SIZE = 1048576KB , FILEGROWTH = 524288KB )
GO
USE [PrimaryFG]
GO
-- If it isn't already the primary filegroup change it to the primary.
IF NOT EXISTS (SELECT name FROM sys.filegroups WHERE is_default=1 AND name = N'DATA') 
	ALTER DATABASE [PrimaryFG] MODIFY FILEGROUP [DATA] DEFAULT
GO

Now when I create a new table it will be created in the DATA filegroup unless I specify otherwise.

CREATE TABLE OnData (col1 int);
CREATE TABLE OnPrimary (col1 int) ON [PRIMARY];
GO
SELECT d.name As DataSpace, ISNULL(i.name,'Heap') AS IndexName, t.name AS TableName
FROM sys.data_spaces d
JOIN sys.indexes i
	ON d.data_space_id = i.data_space_id
JOIN sys.tables t
	ON i.object_id = t.object_id;

The nice thing here is that it helps prevent mistakes. If you want all of your tables in DATA then set your primary filegroup. That way when a developer just creates a table and doesn’t think to change the default (and really, how often do you really specify the filegroup when creating a basic table?) it still goes in the correct place.

SQLStudies

My name is Kenneth Fisher and I am Senior DBA for a large (multi-national) insurance company. I have been working with databases for over 20 years starting with Clarion and Foxpro. I’ve been working with SQL Server for 12 years but have only really started “studying” the subject for the last 3. I don’t have any real "specialities" but I enjoy trouble shooting and teaching. Thus far I’ve earned by MCITP Database Administrator 2008, MCTS Database Administrator 2005, and MCTS Database Developer 2008. I’m currently studying for my MCITP Database Developer 2008 and should start in on the 2012 exams next year. My blog is at www.sqlstudies.com.

Comments

Leave a comment on the original post [sqlstudies.com, opens in a new window]

Loading comments...