How to make a filegroup read only in SQL Server 2005? This question popped up today on tek-tips. This is how you do that: First we will create a new database named TestFilegroup. Next we will add a filegroup named Test1FG1 which contains a file named test1dat3.
The next step is to do an alter database modift filegroup readonly command
Here is the complete script
USE master
go
--Create New DB For Testing
CREATE DATABASE TestFilegroup
go
--Create FileGroup
ALTER DATABASE TestFilegroup
ADD FILEGROUP Test1FG1;
--Add file to fileGroup
ALTER DATABASE TestFilegroup
ADD FILE
(
NAME = test1dat3,
FILENAME = 'c:\t1dat3.ndf',
SIZE = 5MB,
MAXSIZE = 100MB,
FILEGROWTH = 5MB
)
TO FILEGROUP Test1FG1
--Make FileGroup ReadOnly
ALTER DATABASE TestFilegroup
MODIFY FILEGROUP Test1FG1 Read_Only;
Use Read_Only not ReadOnly because the keyword READONLY will be removed in a future version of Microsoft SQL Server. Avoid using READONLY in new development work, and plan to modify applications that currently use READONLY. Use READ_ONLY instead.
Now what happens when you try to create a table on filegroup Test1FG1?
USE TestFilegroup
GO
CREATE TABLE abc (id INT) ON Test1FG1
You will see the following error message
Server: Msg 1924, Level 16, State 2, Line 1
Filegroup 'Test1FG1' is read-only.
You can use sys.filegroups and check the is_read_only column to find out if a filegroup is read only
SELECT is_read_only
FROM sys.filegroups
WHERE name = 'Test1FG1'
Here is the result
is_read_only
------------
1
Using NTFS Compression with Read-Only User-defined Filegroups and Read-Only Databases
SQL Server 2005 supports NTFS compression of read-only user-defined filegroups and read-only databases. You should consider compressing read-only data in the following situations:
You have a large volume of static or historical data that must be available for limited read-only access.
You have limited disk space.
A blog about SQL Server, Books, Movies and life in general
Monday, March 05, 2007
How To Make A FileGroup Read Only in SQL Server 2005
Labels:
SQL Server 2005,
tip
Subscribe to:
Post Comments (Atom)
1 comment:
There is one slight problem with setting filegroups to read only. No one else can be using the database. You need to set the database to single user, set the filegroup to read_only, and then return the database to a multi-user condition.
Post a Comment