Posts filed under 'SQL Server'

SQL Server 2005 SP3 Released

Service pack 3 for SQL Server 2005 was released last week. In it, they have fixed a curious bug that I reported back in January.

The bug occurs when trying to delete rows from a table that have a NULL value for an image column. This works fine normally, but if there is a foreign key referencing the table (to any of its columns), any rows that have had their image column updated to be NULL fail to be deleted. This SQL demonstrates the problem:

-- create two linked tables
CREATE TABLE [dbo].[TableA]
(
    [Identity] [int] NOT NULL IDENTITY(1, 1) PRIMARY KEY,
    [TableB_Identity] [int] NULL
)

CREATE TABLE [dbo].[TableB]
(
    [Identity] [int] NOT NULL IDENTITY(1, 1) PRIMARY KEY,
    [DATA] image NULL
)

ALTER TABLE [TableA] ADD CONSTRAINT [FK_TableA_TableB]
    FOREIGN KEY ([TableB_Identity]) REFERENCES [TableB] ([Identity])

-- insert some data
INSERT INTO [TableB] ([DATA]) VALUES (NULL)
INSERT INTO [TableB] ([DATA]) VALUES (NULL)
INSERT INTO [TableB] ([DATA]) VALUES (NULL)

-- this delete works successfully
DELETE FROM [TableB] WHERE [DATA] IS NULL
SELECT COUNT(*) AS Remaining_Count_Should_Be_0 FROM [TableB]

-- insert some data
INSERT INTO [TableB] ([DATA]) VALUES (NULL)
INSERT INTO [TableB] ([DATA]) VALUES (NULL)
INSERT INTO [TableB] ([DATA]) VALUES (NULL)

-- update the data to be have a NULL value
UPDATE [TableB] SET [DATA] = NULL WHERE [DATA] IS NULL

-- this delete doesn't work
DELETE FROM [TableB] WHERE [DATA] IS NULL
SELECT COUNT(*) AS Remaining_Count_Should_Be_0 FROM [TableB]

-- this delete doesn't work
DELETE FROM [TableB] WHERE ISNULL([DATA], NULL) IS NULL
SELECT COUNT(*) AS Remaining_Count_Should_Be_0 FROM [TableB]

-- this delete does work successfully
DELETE FROM [TableB] WHERE EXISTS
    (
        SELECT * FROM [TableB] AS TB
        WHERE [DATA] IS NULL
        AND TB.[Identity] = [TableB].[Identity]
    )
SELECT COUNT(*) AS Remaining_Count_Should_Be_0 FROM [TableB]

Not all of the delete queries work correctly. The output of the script is four result sets with the count of how many rows are in the table at each point. All of them should be 0 (as is the case on SQL Server 2000), but in SQL SERVER 2005 without SP3 they are actually 0, 3, 3 and 0.

The simple delete query:

DELETE FROM [TableB] WHERE [DATA] IS NULL

does not delete any rows after the values for the Data column have been updated to NULL, even though a similar select query:

SELECT * FROM [TableB] WHERE [DATA] IS NULL

will return rows.

Notably, if either the foreign key is removed, or the:

UPDATE [TableB] SET [DATA] = NULL WHERE [DATA] IS NULL

query is not performed, the script behaves as expected. Additionally, using text or ntext instead of image does not work as well, but using the new varchar(max), nvarchar(max) or varbinary(max) data types does work.

Apparrently, the distinction between NULL values stored as a result of an insert or an update has precendece in the WRITETEXT command:

If the table does not have in row text, SQL Server saves space by not initializing text columns when explicit or implicit null values are added in text columns with INSERT, and no text pointer can be obtained for such nulls. To initialize text columns to NULL, use the UPDATE statement. If the table has in row text, you do not have to initialize the text column for nulls and you can always get a text pointer.

This points to the "text in row" option having a bearing on this behaviour. Indeed, altering this option after creating the tables:

sp_tableoption N'TableB', 'text in row', 'ON'

results in the script working as expected. Useful as a potential workaround.

The bug is present in all versions of SQL Server 2005, but not in SQL Server 2000 or 2008.

A full list of what's changed in SP3 can be found here, with a full list of the bugs fixed here.

Add comment Permalink December 23rd, 2008 Adrian Banks
Subscribe to this feed Bookmark this post on del.icio.us Digg this post on digg.com Share this post

Preventing Accidental Schema Changes To The ‘master’ Database

If you have ever run some SQL within SQL Server Management Studio only to realise that you've run it against the master database by mistake, you'll know that it can sometimes be hard to undo the damage.

A simple way to stop these accidental changes is to create a database trigger that will prevent any schema changes to the master database:

USE master
GO

CREATE TRIGGER StopSchemaChanges ON DATABASE FOR
CREATE_APPLICATION_ROLE, ALTER_APPLICATION_ROLE, DROP_APPLICATION_ROLE,
CREATE_ASSEMBLY, ALTER_ASSEMBLY, DROP_ASSEMBLY,
CREATE_CERTIFICATE, ALTER_CERTIFICATE, DROP_CERTIFICATE,
GRANT_DATABASE, DENY_DATABASE, REVOKE_DATABASE,
CREATE_EVENT_NOTIFICATION, DROP_EVENT_NOTIFICATION,
CREATE_FUNCTION, ALTER_FUNCTION, DROP_FUNCTION,
CREATE_INDEX, ALTER_INDEX, DROP_INDEX,
CREATE_PROCEDURE, ALTER_PROCEDURE, DROP_PROCEDURE,
CREATE_SCHEMA, ALTER_SCHEMA, DROP_SCHEMA,
CREATE_STATISTICS, DROP_STATISTICS, UPDATE_STATISTICS,
CREATE_SYNONYM, DROP_SYNONYM,
CREATE_TABLE, ALTER_TABLE, DROP_TABLE,
CREATE_TRIGGER, ALTER_TRIGGER, DROP_TRIGGER,
CREATE_VIEW, ALTER_VIEW, DROP_VIEW
AS
BEGIN
    RAISERROR(N'Do you really modify the master database?', 16, 1) WITH NOWAIT
    ROLLBACK TRANSACTION
END
GO

Any time you attempt to change the master database, SQL Server will fail with an error. If you do want to make a schema change, simply disable the trigger and then re-enable it once the schema change is complete.

(NB. this only works with SQL Server 2005)

Add comment Permalink June 8th, 2008 Adrian Banks
Subscribe to this feed Bookmark this post on del.icio.us Digg this post on digg.com Share this post

Fixing Database Logins After A Restore

For several years now I've been moving development databases between SQL Servers using backup and restore. When you restore the database on the target server, the logins for the database are invariably broken with the database user having an empty login name, meaning that they cannot log in to the database. My usual fix is to delete the database user and re-add it. Paul Hayman however pointed out a useful stored procedure to fix broken logins:

sp_change_users_login 'Auto_Fix', 'username'

where username is the name of the account to fix.

The Auto_Fix option will attempt to match the broken login with an existing user with the same name.

More information on this can be found in the MSDN documentation. Specific things to note are that it only works with SQL Server and not Windows logins, and that you must be a member of the sysadmin fixed server role for it to work.

Add comment Permalink July 17th, 2007 Adrian Banks
Subscribe to this feed Bookmark this post on del.icio.us Digg this post on digg.com Share this post

Running The OUTPUT Clause From C#

SQL Server 2005 introduced a new feature called the output clause. This enables INSERT, UPDATE and DELETE queries to be run, with the original information which has been changed being returned. This is particularly useful if you want to run a query and know what has been changed by it by returning the identites of the modified rows.

The full documentation for the output clause can be found in SQL Server 2005 Books Online.

In trying to use this feature, I could get it to work in a query window, but when trying it using C# and ADO, it was not obvious how to execute the query and return the results because the ExecuteNonQuery() method of SqlCommand only returns the count of the number of rows that have been updated. After a bit of unsuccessful searching, I came across a post by Keyvan Nayyeri with something that gave me an idea:

OUTPUT clause works like a SELECT statement but its usage differs in INSERT, UPDATE and DELETE commands


Switching my code around to run the update query using the ExecuteReader() method of SqlCommand as would be used for a SELECT query proved to be fruitful, enabling the returned result set to be read.

2 comments Permalink May 1st, 2007 Adrian Banks
Subscribe to this feed Bookmark this post on del.icio.us Digg this post on digg.com Share this post

The Perils Of sp_rename

Andras Belokosztolszki from Red Gate posted an interesting article about the sp_rename stored procedure in SQL Server and the pitfalls that can occur after its use.

When a stored procedure is created, an object is created in the sysobjects table (or the sys.objects view in SQL Server 2005), and the textual definition is stored in the syscomments table (or the sys.sql_modules view in SQL Server 2005).

When using sp_rename to rename a stored procudure, the definition is left intact and only the name is changed in the sysobjects table (or sys.objects view). This means that the definition of the stored procedure stored in database now has the wrong name.

The best way of renaming a stored procedure is to completely delete it and then recreate it with the new name.

The following SQL displays the definitions of all stored procedures in a database alongside their names:

SQL Server 2000

SELECT V2.[name], V1.[text]
    FROM syscomments AS V1, sysobjects AS V2
    WHERE V1.[id] = V2.[id]
    AND (V2.[xtype] = 'P' OR V2.[xtype] = 'F')

SQL Server 2005

SELECT V2.[name], V1.[definition]
    FROM sys.sql_modules AS V1, sys.objects AS V2
    WHERE V1.[object_id] = V2.[object_id]

It is worth noting that enterprise manager uses the sp_rename stored procedure when using the right-click rename option (although SQL Server 2005 management studio does try to correct this problem if you view the definition of a renamed stored procedure by replacing the original stored name with the new one).

Add comment Permalink July 10th, 2006 Adrian Banks
Subscribe to this feed Bookmark this post on del.icio.us Digg this post on digg.com Share this post

Previous Posts


Calendar

March 2017
M T W T F S S
« Oct    
 12345
6789101112
13141516171819
20212223242526
2728293031  

Posts by Month

Posts by Category

RSS Feeds Feeds

Visitors

Visitor Map