Category Archives: #SQLServer

All about Microsoft SQL Server

#0326 – SQL Server – Setting database to READ_ONLY does not change the file-group properties


Last week, I re-learnt something which, according to me, is a little counter-intuitive. I was studying read-only databases out of academic interest and noticed something interesting:

When a database is marked as Read-only, the underlying file/file-groups are not marked Read-only.

Here’s a simple test wherein we:

  1. Create a test database with multiple file-groups (the test works equally well with a single file-group)
  2. Set the database to READ_ONLY
  3. Check the file-group properties
USE master;
GO
--Create the test database
CREATE DATABASE ReadOnlyDB
ON
PRIMARY  (Name=ReadOnlyDB_Primary,
          FileName='C:DatabasesSQL2012ReadOnlyDB_Primary.mdf'
         ),
FILEGROUP SecondaryFG
        (Name=ReadOnlyDB_Secondary,
         FileName='C:DatabasesSQL2012ReadOnlyDB_Secondary.ndf'
        )
LOG ON (Name=ReadOnlyDB_Log,
        FileName='C:DatabasesSQL2012ReadOnlyDB_Log.ldf'
       );
GO

USE master;
GO
--Set the database to READ_ONLY
ALTER DATABASE ReadOnlyDB SET READ_ONLY;
GO

USE ReadOnlyDB;
GO
--Check the File & File-group properties
SELECT sfg.is_read_only,sfg.*
FROM sys.filegroups AS sfg;
GO
SELECT sdf.is_read_only,sdf.*
FROM sys.database_files AS sdf;
GO

image

As can be seen from the output, none of the file-groups were marked as read-only even though the database is read-only. To confirm that the database is indeed read-only, let us attempt to create a table on the database.

USE ReadOnlyDB;
GO
CREATE TABLE TestTbl (Id INT IDENTITY(1,1),
                      Name VARCHAR(50)
                     )
ON SecondaryFG;
GO

Msg 3906, Level 16, State 1, Line 1

Failed to update database “ReadOnlyDB” because the database is read-only.

A possible explanation

The fact that the file-groups are not marked read-only even though the database is read-only is counter-intuitive.

The only possible explanation that I have is that primary file-groups cannot be marked read-only which is why SQL Server does not automatically attempt to mark the file-groups and log files as read-only.

Further Reading

  • SQL Server Myth: Log files are removed when a database is made READ_ONLY [Link]

Until we meet next time,

Be courteous. Drive responsibly.

#0325 – SQL Server – fn_trace_gettable – Get database name change history from default trace


A few weeks ago, I received a very interesting question from one of the readers. The question was:



“Given that no explicit auditing/logging exists on a particular database, can we get a history of all the various names that a database was assigned?”


This is a classic case where the answer is: “It depends!


NOTE: The explanation below requires an understanding of SQL Server’s default tracing mechanism.


Depending upon the needs of the business, it is quite possible that there exist multiple copies of the same database on the same or multiple servers (in a development or QA environment, for example). Hence, it may become very difficult to maintain the database name history within the database (because there would be many questions like – should the history be truncated upon restore; etc). Besides, the database name itself does not have any impact on the operation of the database then why should we maintain a history of the various names that the database has assumed over time?


Therefore, there is no durable log of the database rename activity stored in the database or any of the system databases.


By default, Microsoft SQL Server maintains a default profiler trace that can help administrators get a log of activity primarily related to the configuration options that happened within SQL Server. However, the default trace is limited to a set of files and when the SQL Server fills up all of these files, it rolls over and deletes the first of the files in the set to maintain the same number of trace files by continuing the trace in a new file.


Because a trace is constantly running against the server, the trace would have captured the renaming of the database. Hence, if we query the default trace file, we can get information about database renames, provided that the trace file has not yet been rolled over by SQL Server. Allow me to demonstrate with an example:


The following query creates a database and renames it thrice. It then queries the default trace to get a log of all rename activity.

–Safety check
IF EXISTS(SELECT * FROM sys.databases AS sd WHERE sd.name = ‘BRNAV0325v3’)
DROP DATABASE BRNAV0325v3;
GO

–Now create the test database
CREATE DATABASE BRNAV0325;
GO

–Rename the database (1st time)
ALTER DATABASE BRNAV0325
MODIFY NAME=BRNAV0325v1;
GO

–Rename the database (2nd time)
ALTER DATABASE BRNAV0325v1
MODIFY NAME=BRNAV0325v2;
GO

–Rename the database (3rd time)
ALTER DATABASE BRNAV0325v2
MODIFY NAME=BRNAV0325v3;
GO

–If the default trace is enabled, get the path to the log file
–SELECT * from sys.traces where is_default = 1

–Query the default trace to get a record of database renames
SELECT ft.DatabaseID ,
ft.DatabaseName ,
MIN(ft.StartTime) AS ActivityDate ,
ft.LoginName,
DB_NAME(ft.DatabaseID) AS CurrentDatabaseName
FROM ::fn_trace_gettable( ‘C:Program FilesMicrosoft SQL ServerMSSQL11.SQL2012MSSQLLoglog.trc’ , DEFAULT) AS ft
WHERE ft.EventClass IN( 46 , –CREATE
47 , –DROP
164) –ALTER
AND ft.EventSubclass = 0 –We are not interested in granularity
AND ft.DatabaseID <> 2 –tempdb activity can be ignored
AND ft.IndexID IS NULL –We do not need any table/column activity
–(including statistics)
AND ft.DatabaseName LIKE ‘BRNAV0325%’
GROUP BY ft.DatabaseID,
ft.DatabaseName,
ft.LoginName;
GO

–Cleanup
IF EXISTS(SELECT * FROM sys.databases AS sd WHERE sd.name = ‘BRNAV0325v3’)
DROP DATABASE BRNAV0325v3;
GO


The output looks similar to the following:


image



As you can see, subject to the availability of the necessary data in the default trace, we can use the function – fn_trace_gettable() – to get a record of the database rename operations.


Further Reading



  • sys.fn_trace_gettable [Books On Line Link]
  • Default Trace Server configuration option [Books On Line Link]

Until we meet next time,


Be courteous. Drive responsibly.

#0324 – SQL Server – Script foreign key creation statements


A long time ago, Pinal Dave, a.k.a SQLAuthority (B|T) wrote a post on Two Methods to Retrieve List of Primary Keys and Foreign Keys of Database at the end of which he asked the readers to come up with queries that would re-create the original definition of the primary and foreign keys.

Scripting primary keys is quite easy, but scripting foreign keys is a challenge because of the following:

  1. We have both referenced and referencing tables/columns in the mix
  2. We may have multiple columns and getting the order of the columns in both – referenced and referencing column lists is important (a column A cannot cross-reference to corresponding column B)
  3. We need to (at least everyone should!) specify the update and delete actions

After many years, I got around to this action item and wrote the following script to re-create the original foreign key definition.

USE AdventureWorks2012
GO
;
WITH    ReferentialKeys ( ConstraintName,
                          ReferencedConstraint,
                          DeleteRule,
                          UpdateRule,
                          ReferencingTableSchema,
                          ReferencingTable,
                          ReferencedTableSchema,
                          ReferencedTable )
          AS (
               SELECT   DISTINCT
                        isrc.CONSTRAINT_NAME AS ConstraintName,
                        isrc.UNIQUE_CONSTRAINT_NAME AS ReferencedConstraint,
                        isrc.DELETE_RULE AS DeleteRule,
                        isrc.UPDATE_RULE AS UpdateRule,
                        ReferencingConstraint.TABLE_SCHEMA AS ReferencingTableSchema,
                        ReferencingConstraint.TABLE_NAME AS ReferencingTable,
                        ReferencedConstraint.TABLE_SCHEMA AS ReferencedTableSchema,
                        ReferencedConstraint.TABLE_NAME AS ReferencedTable
               FROM     INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS AS isrc
                        INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS ReferencingConstraint
                                    ON isrc.CONSTRAINT_SCHEMA = ReferencingConstraint.CONSTRAINT_SCHEMA
                                   AND isrc.CONSTRAINT_NAME = ReferencingConstraint.CONSTRAINT_NAME
                        INNER JOIN INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS ReferencedConstraint
                                    ON isrc.UNIQUE_CONSTRAINT_SCHEMA = ReferencedConstraint.CONSTRAINT_SCHEMA
                                   AND isrc.UNIQUE_CONSTRAINT_NAME = ReferencedConstraint.CONSTRAINT_NAME
             ) ,
        ReferencingColumns ( ReferencingConstraint,
                             ReferencedConstraint,
                             ReferencingColumn )
          AS (
               SELECT   ReferentialKeys.ConstraintName AS ReferencingConstraint,
                        ReferentialKeys.ReferencedConstraint AS ReferencedConstraint,
                        CAST((
                               SELECT   ( ','
                                          + QUOTENAME(ReferencingConstraint.COLUMN_NAME) )
                               FROM     INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS ReferencingConstraint
                               WHERE    ReferencingConstraint.CONSTRAINT_NAME = ReferentialKeys.ConstraintName
                               ORDER BY ReferencingConstraint.ORDINAL_POSITION
                             FOR
                               XML PATH('')
                             ) AS NVARCHAR(MAX)) AS ReferencedColumn
               FROM     ReferentialKeys
             ) ,
        ReferencedColumns ( ReferencingConstraint, ReferencedConstraint, ReferencedColumn )
          AS (
               SELECT   ReferentialKeys.ConstraintName AS ReferencingConstraint,
                        ReferentialKeys.ReferencedConstraint AS ReferencedConstraint,
                        CAST((
                               SELECT   ( ','
                                          + QUOTENAME(ReferencedConstraint.COLUMN_NAME) )
                               FROM     INFORMATION_SCHEMA.KEY_COLUMN_USAGE AS ReferencedConstraint
                               WHERE    ReferencedConstraint.CONSTRAINT_NAME = ReferentialKeys.ReferencedConstraint
                               ORDER BY ReferencedConstraint.ORDINAL_POSITION
                             FOR
                               XML PATH('')
                             ) AS NVARCHAR(MAX)) AS ReferencedColumn
               FROM     ReferentialKeys
             )
    SELECT  'IF OBJECT_ID(''' + QUOTENAME(ReferentialKeys.ConstraintName)
            + ''',''F'') IS NOT NULL
    BEGIN
        ALTER TABLE ' + QUOTENAME(ReferentialKeys.ReferencingTableSchema)
            + '.' + QUOTENAME(ReferentialKeys.ReferencingTable)
            + '
            WITH CHECK ADD CONSTRAINT '
            + QUOTENAME(ReferentialKeys.ConstraintName) + ' FOREIGN KEY ('
            + SUBSTRING(ReferencingColumns.ReferencingColumn, 2,LEN(ReferencingColumns.ReferencingColumn))
            + ') REFERENCES '
            + QUOTENAME(ReferentialKeys.ReferencedTableSchema) + '.'
            + QUOTENAME(ReferentialKeys.ReferencedTable) + ' ('
            + SUBSTRING(ReferencedColumns.ReferencedColumn, 2,LEN(ReferencedColumns.ReferencedColumn)) + ')'
            + ' ON DELETE ' + ReferentialKeys.DeleteRule + ' ON UPDATE ' + ReferentialKeys.UpdateRule + ';
    END
GO'
    FROM    ReferentialKeys
            INNER JOIN ReferencingColumns
                    ON ReferentialKeys.ConstraintName = ReferencingColumns.ReferencingConstraint
                   AND ReferentialKeys.ReferencedConstraint = ReferencingColumns.ReferencedConstraint
            INNER JOIN ReferencedColumns
                    ON ReferentialKeys.ConstraintName = ReferencedColumns.ReferencingConstraint
                   AND ReferentialKeys.ReferencedConstraint = ReferencedColumns.ReferencedConstraint
    ORDER BY ReferentialKeys.ReferencingTableSchema,
             ReferentialKeys.ReferencingTable,
             ReferentialKeys.ConstraintName
GO

It’s now time to take this query around for a test drive. Here’s the definition of “FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductID” that my query produces (formatted for better readability):

IF OBJECT_ID('[FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductID]','F') IS NOT NULL
    BEGIN
        ALTER TABLE [Sales].[SalesOrderDetail]
            WITH CHECK ADD CONSTRAINT [FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductID]
                       FOREIGN KEY ([SpecialOfferID],[ProductID])
                       REFERENCES [Sales].[SpecialOfferProduct] ([SpecialOfferID],[ProductID])
                       ON DELETE NO ACTION
                       ON UPDATE NO ACTION;
    END
GO

And here’s the query that SSMS produces when I ask it to script out the key for me.

IF NOT EXISTS (SELECT *
               FROM sys.foreign_keys
               WHERE object_id = OBJECT_ID(N'[Sales].[FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductID]')
                 AND parent_object_id = OBJECT_ID(N'[Sales].[SalesOrderDetail]'))
    ALTER TABLE [Sales].[SalesOrderDetail]
        WITH CHECK ADD  CONSTRAINT [FK_SalesOrderDetail_SpecialOfferProduct_SpecialOfferIDProductID]
                   FOREIGN KEY([SpecialOfferID], [ProductID])
                   REFERENCES [Sales].[SpecialOfferProduct] ([SpecialOfferID], [ProductID])
GO

Fairly accurate, wouldn’t you say? 🙂

Do share any such useful scripts that you may have in the Scripts page on this site.

Until we meet next time,

Be courteous. Drive responsibly.

#0323 – Do you use the re-usable code that you share with others?


Today’s post is not specific to SQL Server, but to a general developer mindset. It all started with the following tip that came up when launching Visual Studio 6.0 (yes, I do work on products written in VC++ 6.0, and I always have Visual Studio show me tips on launch).

image

Code, just like software architecture is a dynamic thing. Over time, the code would undergo various transformations (to incorporate various requirements), become more configurable and would require corrections as and when defects are discovered.

In my many years of experience, I have worked with two kinds of developers:

  1. One group comprises of those who rely solely on memory and/or search engines and believe all pieces of code can be written from scratch every time
  2. Then comes the other group who religiously maintain a repository of all pieces of code that they have found useful

As time passes, the later group of developers would have invested significant time in documenting, indexing and improving upon these code snippets to ensure that they can reach out to the ever evolving and self-correcting code faster. Whereas the former group of people might end up making the same mistakes over and over again.

Learning from this group, I maintain an SSMS solution that contains all the possibly re-usable and PoC level T-SQL code that I have ever written. I find that this helps me write a query faster and with improved quality.

I encourage every developer to start out with a simple repository of all possible re-usable code that they own and once it becomes a habit, watch it evolve over time. It will surely help to write the code right the first time!

Until we meet next time,

Be courteous. Drive responsibly.

#0322 – SQL Server – Why is it not a good idea to implement NOT NULL check as a CHECK constraint


I continue to be surprised by the various practices that developers use to achieve the same result.


The common understanding with SQL Server DDL is that in most cases, there is only one method to implement a given design element. For example, to ensure that a column does not accept NULL values, the solution that comes to mind is to define it as a NOT NULL column.


Recently, I came across a trainee who proposed to implement the NOT NULL requirement for a given column in a way that’s not conventional – he proposed to use CHECK constraints. I had never heard of anyone using CHECK constraints to enforce a NOT NULL check, but I liked the thought process and hence wrote a quick prototype to demonstrate why this was not a good idea.


The following is how I explained why we don’t use CHECK constraints to enfore NOT NULL values (for sake of brevity, I am demonstrating with a table that has only one column).

USE tempdb ;
GO

--Safety Check
IF OBJECT_ID('dbo.NotNullCheckConstraint', 'U') IS NOT NULL 
    BEGIN
        DROP TABLE dbo.NotNullCheckConstraint ;
    END
GO

--Table kept short for sake of brevity
CREATE TABLE dbo.NotNullCheckConstraint ( Age INT ) ;
GO

ALTER TABLE dbo.NotNullCheckConstraint
    ADD CONSTRAINT chk_AgeSpecified CHECK ( Age > 0 ) ;
GO

On most environments, though, this will not stop the user from entering NULLs. Let’s try it out:

USE tempdb;
GO
--Insert Test Data to prove that the CHECK constraint does not stop NULL values
INSERT  INTO dbo.NotNullCheckConstraint ( Age )
VALUES  ( NULL ),
        ( NULL ) ;
GO

--Select data from the table
SELECT  Age
FROM    dbo.NotNullCheckConstraint ;
GO
/*
Results:
--------
Age
--------
NULL
NULL
*/

The only real way to enforce a NOT NULL values via CHECK constraint is to alter the constraint to the following:

--Truncate the test table
TRUNCATE TABLE dbo.NotNullCheckConstraint;
GO

--Drop the old constraint
ALTER TABLE dbo.NotNullCheckConstraint 
    DROP CONSTRAINT chk_AgeSpecified ;
GO

--Create a new constraint
ALTER TABLE dbo.NotNullCheckConstraint
    ADD CONSTRAINT chk_AgeSpecifiedWithNotNullCheck CHECK ( Age IS NOT NULL
                                                            AND Age > 0 ) ;
GO

Let us now try to insert NULL values into the table:

USE tempdb ;
GO
--Insert Test Data to prove that the new CHECK constraint did stop NULL values
INSERT  INTO dbo.NotNullCheckConstraint ( Age )
VALUES  ( NULL ),
        ( NULL ) ;
GO

--Select data from the table
SELECT  Age
FROM    dbo.NotNullCheckConstraint ;
GO
/*
Results:
--------
Age
--------
*/

We encounter the following error message:


Msg 547, Level 16, State 0, Line 2
The INSERT statement conflicted with the CHECK constraint “chk_AgeSpecifiedWithNotNullCheck”. The conflict occurred in database “tempdb”, table “dbo.NotNullCheckConstraint”, column ‘Age’.

The statement has been terminated.


(0 row(s) affected)


In this case, the CHECK constraint did indeed prevent us from inserting NULL values into the table.


But, is this a good idea?



The answer, in my humble opinion is – No.


And, I have two reaons for it:



  1. CHECK constraints are ideally suited to enforce business rules and business logic rather than data integrity


    • They are evaluated after the SQL Server database engine is sure that the input values do not violate any properties or boundaries of the defined column

    • I even wrote an article about the constraint execution sequence on SQLServerCentral.com here – Leveraging Constraint Evaluation Sequence in SQL Server. The examples in the article demonstrate how the NOT NULL constraint is evaluated before CHECK constraints

  2. A CHECK constraint can be disabled by a user having sufficient priviledges thereby allowing the application to insert NULL values – a NOT NULL column definition on the other hand would remain in effect

Here’s a quick check for point #2 (disabling a CHECK constraint may allow to enter invalid data).

USE tempdb;
GO
--Now, disable the constraint
ALTER TABLE dbo.NotNullCheckConstraint
    NOCHECK CONSTRAINT chk_AgeSpecifiedWithNotNullCheck;
GO

--Insert Test Data to prove that the new CHECK constraint did NOT stop NULL values
INSERT  INTO dbo.NotNullCheckConstraint ( Age )
VALUES  ( NULL ),
        ( NULL ) ;
GO

--Select data from the table
SELECT  Age
FROM    dbo.NotNullCheckConstraint ;
GO
/*
Results:
--------
Age
--------
NULL
NULL
*/

/********************************************************************************/
USE tempdb ;
GO
--Now, re-enable the constraint
--Notice no error is reported
ALTER TABLE dbo.NotNullCheckConstraint
    CHECK CONSTRAINT chk_AgeSpecifiedWithNotNullCheck;
GO

--Insert Test Data to prove that the new CHECK constraint did stop NULL values
--This will report an error
INSERT  INTO dbo.NotNullCheckConstraint ( Age )
VALUES  ( NULL ),
        ( NULL ) ;
GO

--Select data from the table - results from earlier run are still available
SELECT  Age
FROM    dbo.NotNullCheckConstraint ;
GO
/*
Results:
--------
Age
--------
NULL
NULL
*/

Summary


Roughly defined, patterns are common solutions to common problems. There is a reason why Patterns and Practices were developed and this a classic example. A CHECK constraint can be used to enforce a NOT NULL check, but it is not a normal pattern and the reaons are:



  1. CHECK constraints are evaluated after NOT NULL validation

  2. CHECK constraints may be disabled allowing the user to enter invalid data into the table

Further Reading



  • Leveraging Constraint Evaluation Sequence in SQL Server [Link]

  • Using Regular Expressions with CHECK constraints [Link]

  • Defining CHECK constraints on computed columns [Link]

  • Defining “complex” CHECK constraints [Link]

Until we meet next time,


Be courteous. Drive responsibly.