This seems to be the third week that I am writing about ReadOnly databases, this blog is in continuation of last weeks notes. When I wrote the notes from last week, one of my blog reader said if it is possible to get the ReadOnly error without making the database into a ReadOnly database. This got me thinking and I couldn’t sleep that day. And a quick call to my friend to get some ideas – the answer was simple – using Snapshots.
I couldn’t control my excitement and this triggered me to write this special case scenario. As we execute the script, we will learn some of the behavior.
Let us start by creating our database which will be used for testing.
CREATE DATABASE [ReadOnlyDB] CONTAINMENT = NONE ON PRIMARY ( NAME = N'ReadOnlyDB', FILENAME = N'C:\Temp\ReadOnlyDB.mdf' , SIZE = 4024KB , FILEGROWTH = 1024KB ) LOG ON ( NAME = N'ReadOnlyDB_log', FILENAME = N'C:\Temp\ReadOnlyDB_log.ldf' , SIZE = 20480KB , FILEGROWTH = 10%) GO USE ReadOnlyDB GO -- Creating our table CREATE TABLE tbl_SQLAuth (id INT, Longname CHAR(8000)) GO
Next let us go ahead and create a snapshot database out of our ReadOnlyDB.
-- Create a snapshot on our DB CREATE DATABASE ReadOnlyDB_SS ON ( NAME = ReadOnlyDB, FILENAME = 'C:\Temp\ReadOnlyDB_data_1800.ss' ) AS SNAPSHOT OF ReadOnlyDB; GO
Now that our snapshot database (ReadOnlyDB_SS) is created, it is important to know that snapshot databases are created as ReadOnly databases. The behavior is similar to creating ReadOnly Databases. To test this, let us try to insert some data into our Snapshot DB.
USE ReadOnlyDB_SS GO INSERT INTO tbl_SQLAuth VALUES (1, 'SQLAuth'); GO
Now we will be presented with the same familiar error (3906):
Msg 3906, Level 16, State 1, Line 25
Failed to update database “ReadOnlyDB_SS” because the database is read-only.
Even though we have not explicitly marked the snapshot database as Readonly we are getting this error. I was curious to know, what will happen if we try to mark the snapshot database as ReadOnly again. The error is self-explanatory.
-- Let us set the Snapshot DB as READ_ONLY USE MASTER GO ALTER DATABASE [ReadOnlyDB_SS] SET READ_ONLY GO
Msg 5093, Level 16, State 1, Line 31
The operation cannot be performed on a database snapshot.
Msg 5069, Level 16, State 1, Line 31
ALTER DATABASE statement failed.
If that was easy, what will happen if we try to make the snapshot database to read_write? The error is self-explanatory again here:
USE [master] GO ALTER DATABASE [ReadOnlyDB_SS] SET READ_WRITE WITH NO_WAIT GO
Msg 5093, Level 16, State 1, Line 37
The operation cannot be performed on a database snapshot.
Msg 5069, Level 16, State 1, Line 37
ALTER DATABASE statement failed.
Now that gives us two learnings, we cannot mark a Snapshot database as ReadOnly and nor can we mark a snapshot database as Read_Write enabled.
With these learnings in place, let us do the cleanup. Make sure to drop the Snapshot database before deleting the main database. So our cleanup script for this blog looks:
-- Clean up time USE MASTER GO DROP DATABASE ReadOnlyDB_SS GO DROP DATABASE ReadOnlyDB GO
Reference: Pinal Dave (https://blog.sqlauthority.com)
1 Comment. Leave new
Hi Pinal Sir, Can we create snapshot from readonly database?