Archive

Archive for the ‘SQL Tips’ Category

‘NOCHECK’ vs ‘WITH NOCHECK’… while creating disabled Foreign Key (FK) constraint

March 14, 2012 2 comments

I dicussed about disabling FK constraints in one of my previous post to UPDATE/DELETE records to avoid some conflicts, check this [link] for more info.

There is an option while adding a Constraint to a table:

-- Syntax:
ALTER TABLE TABLE_NAME WITH NOCHECK 
ADD CONSTRAINT FK_CONSTRAINT_NAME FOREIGN KEY(COL_NAME_ID)
REFERENCES OTHER_REF_TABLE (OTHER_TABLE_COL_NAME_ID)

But this doesn’t disable the FK constraint, instead it creates the FK constraint without checking existing records.

You will need to issue a separate ALTER TABLE statement to disable the FK constraint:

-- Syntax:
ALTER TABLE TABLE_NAME NOCHECK CONSTRAINT FK_CONSTRAINT_NAME

So, what’s the difference here when we apply ‘WITH NOCHECK’ vs ‘NOCHECK’?

Let’s check this by taking the [Sales].[SalesOrderDetail] table from AdventureWorks database:

USE [AdventureWorks2008R2]
GO

-- Here I just created the script of [Sales].[SalesOrderDetail] table and stripped off the unwanted parts and changed the table name to [Sales].[SalesOrderDetailTemp]
CREATE TABLE [Sales].[SalesOrderDetailTemp](
	[SalesOrderID] [int] NOT NULL,
	[SalesOrderDetailID] [int] IDENTITY(1,1) NOT NULL,
	[CarrierTrackingNumber] [nvarchar](25) NULL,
	[OrderQty] [smallint] NOT NULL,
	[ProductID] [int] NOT NULL,
	[SpecialOfferID] [int] NOT NULL,
	[UnitPrice] [money] NOT NULL,
	[UnitPriceDiscount] [money] NOT NULL,
	[rowguid] [uniqueidentifier] ROWGUIDCOL NOT NULL,
	[ModifiedDate] [datetime] NOT NULL,
 CONSTRAINT [PK_SalesOrderDetailTemp_SalesOrderID_SalesOrderDetailID] 
 PRIMARY KEY CLUSTERED (
	[SalesOrderID] ASC,
	[SalesOrderDetailID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
GO

-- Let's create a FK constraint with 'WITH NOCHECK' option
ALTER TABLE [Sales].[SalesOrderDetailTemp]  
	WITH NOCHECK 
	ADD CONSTRAINT [FK_SalesOrderDetailTemp_SalesOrderHeader_SalesOrderID] FOREIGN KEY([SalesOrderID])
	REFERENCES [Sales].[SalesOrderHeader] ([SalesOrderID])
ON DELETE NO ACTION
GO

Now, go to Object Explorer check the Table -> Keys. Right click on the FK and select Modify. Check the following option on the FK Relationship popup box:
– General -> Check existing data on Creation or Re-Enabling = No
– Table Designer -> Enforce foreign key constraint = Yes

This shows that the FK constriant is still enabled but it didn’t validated the existing records while creating the FK.

Now to really disable the FK we will just have to use the NOCHECK option without using the WITH keyword:

ALTER TABLE [Sales].[SalesOrderDetailTemp]  
	NOCHECK CONSTRAINT [FK_SalesOrderDetailTemp_SalesOrderHeader_SalesOrderID]
GO

Now, check again the Table -> Keys in Object Explorer. You will see the second option ‘Enforce foreign key constraint’ has changed to ‘No’ in the FK Relationship popup box.

-- Final cleanup
DROP TABLE [Sales].[SalesOrderDetailTemp]
GO

So, finally we saw the difference in using the NOCHECK option by using ‘WITH’ and without ‘WITH’ keyword.
And you cannot directly add a Disabled Constraint to a table. You will need to create the FK Constraint first then only you can disable it by using another ALTER TABLE statement.

Best Practices while creating Stored Procedures

February 26, 2012 8 comments

Stored Procedures in SQL Server provides lot of benefits compared to single/multiple adhoc SQL statements. They help in achieving consistent implementation of logic across applications and improve performance. They also provides us flexibility to design desired business rules and logic by combining various SQL statements, control flow IF-ELSE statements, WHILE loops, and other programming constructs.

Thus to design them it requires a generic approach and some best practices that comes with experience as you work with them. I’m listing some of the best practices that must be followed everytime you create Stored Procedures:

1. SET NOCOUNT ON: Always use ‘SET NOCOUNT ON’ statement at the begening of your code inside the SP to reduce unnecessary network round trips.

2. PARAMETER SNIFFING: Do not use SP parameters directly within the WHERE clause of SQL statements. This may cause the case of Prameter Sniffing. To avod this assign the parameter values to local variables and then use them with SQL queries.

3. Use table variables: Try to use table variables instead of temporary tables inside the SP to cache small record sets whenever possible.

4. Use of Temp Tables: If you think that the temporary record set may exceed upto millions of rows, then try using temporary table instead of table variables. Also try creating indexes on temporary tables if required.

5. Avoid using CURSORS: This will make your SP slow and degrade the performance. Try using more effecient SET based approaches instead of using CURSORS.

6. Use TRY-CATCH block: for error handling, more info [link].

7. Using Transactions: Use Transactions by using BEGIN TRANSACTION and COMMIT/ROLLBACK TRANSACTION blocks to make sure that your actions follow ACID properties [link]. But keep the transctions as short as possible to create less blocking in database and thus avoiding deadlocks.

8. Aliasing objects: Do not use SQL Server reserve keywords while naming SQL Server objects, like for: tables, columns, views, etc. Although it allows most of the time, but its better to use other and better naming conventions.

9. Avoid GOTO stmt: Do not use GOTO statements in your code as it is considered a bad programming practice (and in every other programming language). Try comming up with a better approach/logic, use conditional IF-ELSE logic, WHILE loops and other programming constructs.

10. Avoid ‘sp_’ prefix : Do not prefix the SP name with ‘sp_’. If it begins with ‘sp_’ then the compiler will first search it in master database and then in the current one, thus delaying the execution.

11. Use fully qualified objects name: in your SQL queries, this helps in quickly finding the cached/compiled plan. Also execute the SP by using its fully qualified name, like: EXEC dbo.SPname

12. Use WITH ENCRYPTION: You can also use ‘WITH ENCRYPTION’ option while creating SP to hide the code.

13. Add Comments: Try to put comments wherever possible to give details and idea to other developers what actually your code is doing.

14. Use BEGIN-END code block: Try to bind your whole SP code within BEGIN-END block. Although it is optional but it looks good and gives a better picture.

16. Beautify your code: Well indent your code by uisng TABs, Spaces and New line (ENTER). Try going vertically downwards with your code rather expanding horizontally. This will make your code easy to read and more understandable to other developers.

17. Use following template to create your SP:

-- ================================================
-- Template generated from Template Explorer using:
-- Create Procedure (New Menu).SQL
--
-- Use the Specify Values for Template Parameters 
-- command (Ctrl-Shift-M) to fill in the parameter 
-- values below.
--
-- This block of comments will not be included in
-- the definition of the procedure.
-- ================================================
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Author:		<Author,,Name>
-- Create date: <Create Date,,>
-- Description:	<Description,,>
-- =============================================
CREATE PROCEDURE <Procedure_Name, sysname, ProcedureName> 
	-- Add the parameters for the stored procedure here
	<@Param1, sysname, @p1> <Datatype_For_Param1, , int> = <Default_Value_For_Param1, , 0>, 
	<@Param2, sysname, @p2> <Datatype_For_Param2, , int> = <Default_Value_For_Param2, , 0>
AS
BEGIN
	-- SET NOCOUNT ON added to prevent extra result sets from
	-- interfering with SELECT statements.
	SET NOCOUNT ON;

    -- Insert statements for procedure here
	SELECT <@Param1, sysname, @p1>, <@Param2, sysname, @p2>
END
GO

You can also generate this template, in Object Explorer goto Database -> Programability -> Stored Procedures: Right click and select ‘New Stored Procedure…’. The above code will get generated.
 

>> Check & Subscribe my [YouTube videos] on SQL Server.
 


Recursive CTE error – The maximum recursion 100 has been exhausted before statement completion

December 23, 2011 12 comments

One of the most benefit of CTE (Common Table Expressions) is that we can create recursive queries with them. In my previous posts I’ve discussed this topic with some good examples, link.

An incorrectly composed recursive CTE may cause an infinite loop. So recursive CTEs should be designed very carefully and the recursion level should be checked. To prevent it to run infinitely SQL Server’s default recursion level is set to 100. But you can change the level by using the MAXRECURSION option/hint. The recursion level ranges from 0 and 32,767.

If your CTEs recursion level crosses the limit then following error is thrown by SQL Server engine:
Msg 530, Level 16, State 1, Line 11
The statement terminated. The maximum recursion 100 has been exhausted before statement completion.

Let’s check this with an example discussed in MSDN TSQL forum, link:

DECLARE
	@startDate DATETIME,
	@endDate DATETIME

SET @startDate = '11/10/2011'
SET @endDate = '03/25/2012'

; WITH CTE AS (
	SELECT
		YEAR(@startDate) AS 'yr',
		MONTH(@startDate) AS 'mm',
		DATENAME(mm, @startDate) AS 'mon',
		DATEPART(d,@startDate) AS 'dd',
		@startDate 'new_date'
	UNION ALL
	SELECT
		YEAR(new_date) AS 'yr',
		MONTH(new_date) AS 'mm',
		DATENAME(mm, new_date) AS 'mon',
		DATEPART(d,@startDate) AS 'dd',
		DATEADD(d,1,new_date) 'new_date'
	FROM CTE
	WHERE new_date < @endDate
	)
SELECT yr AS 'Year', mon AS 'Month', count(dd) AS 'Days'
FROM CTE
GROUP BY mon, yr, mm
ORDER BY yr, mm
OPTION (MAXRECURSION 1000)
Output:-

Year	Month		Days
2011	November	22
2011	December	31
2012	January		31
2012	February	29
2012	March		24

Here, by applying “OPTION (MAXRECURSION 1000)”, we can set the recursion level, so that it does not go infinite.

Note: Restriction of recursive CTE is – “A view that contains a recursive CTE cannot be used to update data”.

More info on: http://msdn.microsoft.com/en-us/library/ms175972.aspx

Using IDENTITY function with SELECT statement in SQL Server

December 15, 2011 6 comments

In MS BOL for IDENTITY columns it is mentioned that [link]: “It creates an identity column in a table. This property is used with the CREATE TABLE and ALTER TABLE Transact-SQL statements.”

But experimenting with IDENTITY function I learnt this new thing with is not mentioned (or I could not find) anywhere in MS BOL that: “IDENTITY function can also be used with a SELECT statement but with some condition.”

Let’s check what’s that condition is:

USE [AdventureWorks]
GO

-- Let's use Person.Contact table in our SELECT statement and add a new column as IDENTITY function to it:
SELECT 
	IDENTITY (INT, 100, 5) AS NEW_ID, 
	ContactID, Title, 
	FirstName, 
	MiddleName, 
	LastName, 
	EmailAddress, 
	Phone
FROM Person.Contact

Error Msg thrown:
Msg 177, Level 15, State 1, Line 1
The IDENTITY function can only be used when the SELECT statement has an INTO clause.

As per the error msg we cannot add an IDENTITY column to a SELECT query. The SELECT should be followed by an INTO clause. This way a new table will be created and records will be entered with the new IDENTITY column.

-- Let's add INTO clause in SELECT statement:
SELECT 
	IDENTITY (INT, 100, 5) AS NEW_ID, 
	ContactID, 
	Title, 
	FirstName, 
	MiddleName, 
	LastName, 
	EmailAddress, 
	Phone
INTO #tempTable
FROM Person.Contact

Again an Error Msg:
Msg 8108, Level 16, State 1, Line 1
Cannot add identity column, using the SELECT INTO statement, to table ‘#tempTable’, which already has column ‘ContactID’ that inherits the identity property.

Completely agree with this!!! You cannot have 2 IDENTITY columns in a single table.

-- So we will remove the ContactID column as we want to have new ID column.
SELECT 
	IDENTITY (INT, 100, 5) AS NEW_ID, 
	Title, 
	FirstName, 
	MiddleName, 
	LastName, 
	EmailAddress, 
	Phone
INTO #tempTable
FROM Person.Contact
-- This worked perfectly.

-- Now let's check the newly created temp table and inserted records:
select * from #tempTable

-- Output below shows selected records from Person.Contact table with a new column having values starting from 100 with a gap of 5:

-- Final Cleanup
DROP TABLE #tempTable

 

>> Check & Subscribe my [YouTube videos] on SQL Server.
 

Check the same demo here in YouTube:


T-SQL Query for SORTing Numbers stored as String (VARCHAR)

December 6, 2011 2 comments

Many people come to me as a point of SQL reference and ask, “How can we sort the numbers if they are stored in a VARCHAR column in a table?”.
This morning one guy approached me and asked the same question again.
So this as a generic question I thought to post it in my blog.

Let’s check this by a simple example:

-- Create table and insert some test data:
DECLARE @StringNbrs TABLE (nbr VARCHAR(10))

INSERT INTO @StringNbrs
SELECT C
FROM (VALUES ('681'),
	('21'),
	('9'),
	('1'),
	('401'),
	('158'),
	('1000')) AS T(C)

-- Using simple ORDER BY clause:
SELECT nbr
FROM @StringNbrs
ORDER BY nbr
Output:-

nbr
1
1000
158
21
401
681
9

The above query with ORDER BY clause won’t sort the nbr column as required.

-- =====================================================================
-- Let's see how can we sort the nbr column with 2 methods given below:-
-- =====================================================================

-- Method #1: Using CAST/CONVERT with ORDER BY clause:
SELECT nbr
FROM @StringNbrs
ORDER BY CAST(nbr as INT)

-- Method #2: Another approach by using REPLICATE function in ORDER BY clause:
SELECT nbr
FROM @StringNbrs
ORDER BY REPLICATE('0',4-LEN(nbr)) + nbr
Sorted Output:-

nbr
1
9
21
158
401
681
1000
Categories: SQL Tips Tags: ,