January 15, 2013 at 9:44 am
Hello,
Can I put tabels in read only mode?
Thank you
Julia
January 15, 2013 at 10:55 am
not directly, but you could move them to a separate filegroup and make that read only, or do it via permissions (only select granted or only access via stored procs)
---------------------------------------------------------------------
January 15, 2013 at 11:02 am
Can you give me an example please
January 15, 2013 at 11:11 am
here's something i put together for a different post that was talking about setting a table to read only:
this is not copy/paste/execute code, but rather, amodel to use to modify and step through to comprehend what is going on.
USE [master]
GO
ALTER DATABASE SandBox ADD FILEGROUP onlyLookups
GO
ALTER DATABASE [SandBox] ADD FILE ( NAME = N'SandBox_Lookups',
FILENAME = N'C:\Program Files\Microsoft SQL Server\MSSQL10.MSSQLSERVER\MSSQL\DATA\SandBox_Lookups.ndf' ,
SIZE = 2048KB ,
FILEGROWTH = 1024KB )
TO FILEGROUP [OnlyLookups]
GO
USE [SandBox]
GO
declare @readonly bit
SELECT @readonly=convert(bit, (status & 0x08)) FROM sysfilegroups WHERE groupname=N'OnlyLookups'
if(@readonly=0)
ALTER DATABASE [SandBox] MODIFY FILEGROUP [OnlyLookups] READONLY
GO
USE [master]
GO
declare @readonly bit
SELECT @readonly=convert(bit, (status & 0x08)) FROM sysfilegroups WHERE groupname=N'OnlyLookups'
if(@readonly=0)
ALTER DATABASE [SandBox] MODIFY FILEGROUP [OnlyLookups] READONLY
GO
--are we readwriteable or not?
USE [SandBox]
GO
--#################################################################################################
--toggle read only, add table, put it back
--#################################################################################################
declare @readonly bit
SELECT @readonly=convert(bit, (status & 0x08)) FROM sysfilegroups WHERE groupname=N'OnlyLookups'
if(@readonly=1)
ALTER DATABASE [SandBox] MODIFY FILEGROUP [OnlyLookups] READWRITE
GO
--switch db context so we can alter
USE [master]
GO
declare @readonly bit
SELECT @readonly=convert(bit, (status & 0x08)) FROM sysfilegroups WHERE groupname=N'OnlyLookups'
if(@readonly=1)
ALTER DATABASE [SandBox] MODIFY FILEGROUP [OnlyLookups] READWRITE
GO
--#################################################################################################
--add table
--#################################################################################################
USE [SandBox]
GO
CREATE TABLE [dbo].[CITYDATA] (
[CITYNAME] VARCHAR(28) NULL,
[COUNTYNAME] VARCHAR(64) NULL,
[STATE] VARCHAR(2) NULL,
[STATEFIPS] VARCHAR(2) NULL,
[COUNTYFIPS] VARCHAR(3) NULL,
[ZIPCODE] VARCHAR(5) NULL,
[STATETBLKEY] INT NULL,
[COUNTYTBLKEY] INT NULL,
[CBSA] AS ([STATEFIPS]+[COUNTYFIPS]))
ON onlyLookups
--#################################################################################################
--toggle read only back again
--#################################################################################################
USE [SandBox]
GO
declare @readonly bit
SELECT @readonly=convert(bit, (status & 0x08)) FROM sysfilegroups WHERE groupname=N'OnlyLookups'
if(@readonly=0)
ALTER DATABASE [SandBox] MODIFY FILEGROUP [OnlyLookups] READONLY
GO
USE [master]
GO
declare @readonly bit
SELECT @readonly=convert(bit, (status & 0x08)) FROM sysfilegroups WHERE groupname=N'OnlyLookups'
if(@readonly=0)
ALTER DATABASE [SandBox] MODIFY FILEGROUP [OnlyLookups] READONLY
GO
Lowell
January 15, 2013 at 12:38 pm
Thank you,but how would you add this to table?
January 15, 2013 at 12:52 pm
Other way around. This isn't something you add to a table. Rather you move the table into a separate filegroup and mark the filegroup read only (tables can't be read only, only filegroups or databases)
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
January 15, 2013 at 2:31 pm
Thank you,How you move the table into a separate filegroup?
January 15, 2013 at 2:35 pm
Krasavita (1/15/2013)
Thank you,How you move the table into a separate filegroup?
peek at the code i posted, which creates a new table in the filegroup.
for an existing table, you can Use create index ... with drop_existing for the clustered index and specify the desired filegroup for the place that the index must be created on. , which effectively "moves" the table to the new filegroup.
Lowell
January 16, 2013 at 10:03 am
When I tried to create clustered index as you said and assign to read only file group,I get an error message:that can't save because this file group is readonly
January 16, 2013 at 10:07 am
Krasavita (1/16/2013)
When I tried to create clustered index as you said and assign to read only file group,I get an error message:that can't save because this file group is readonly
again, look at the code i posted.
i toggle the group to read-write, add the table/index, and then toggle it back to read only.
you will have to do the same,.
Lowell
Viewing 10 posts - 1 through 9 (of 9 total)
You must be logged in to reply to this topic. Login to reply