SQL Tips by Namwar Rizvi

May 2, 2007

Improving Performance of UDF by using SCHEMABINDING

Filed under: Performance,Query,SCHEMABINDING,Tuning,UDF — namwar @ 10:49 PM

Ever wondered what happens to your queries when you use some UDF which does not touch any table but even then your query becomes slow???
How can we improve that query?
Most of us think that there is no other way except to remove UDF in this scenario.

May be that can be one solution but take a closer look at query plan and you will find “Spooler” operator whose functionality according to Microsoft definition is
“Stores the data from the input into a temporary table in order to optimize rewinds”

SQL Server 2005 uses this operator when the UDF is not SCHEMABIND to ensure that any DDL change will not break the operation of UDF.

This extra step slows down the query execution. To get the best performance, make sure you always bind your UDF even if it is not using any table or view.

Following is the simple example to demonstrate this behavior:

Set NoCount On
–Create Sample Table
CREATE TABLE dbo.tblItems
(
ItemID int NOT NULL IDENTITY (1, 1),
ItemName nvarchar(50) NOT NULL

) ON [PRIMARY]
GO

ALTER TABLE dbo.tblItems ADD CONSTRAINT
PK_Table_1 PRIMARY KEY CLUSTERED

( ItemID )
GO

–Insert 100000 rows
Print ‘Inserting 100000 rows-Start:’+convert(varchar,GetDate(),113)
Go

Declare @m_Counter int
Select @m_Counter=1
While @m_Counter <100001
Begin
Insert Into dbo.tblItems (ItemName) Values
(‘ItemNo:’+convert(varchar,@m_Counter))
Select @m_Counter=@m_Counter+1

End
Go
Print ‘Inserting 100000 rows-Finish:’+convert(varchar,GetDate(),113)
Go
–Create a Sample UDF without Schema Binding
CREATE FUNCTION dbo.SetValueWithoutSchemaBinding(@p_value nvarchar(50))
RETURNS nvarchar(50)
BEGIN
RETURN @p_value+‘-‘+ ‘WO’
END
Go
–Create a Sample UDF with Schema Binding
CREATE FUNCTION dbo.SetValueWithSchemaBinding(@p_value nvarchar(50))
RETURNS nvarchar(50)
With SchemaBinding
BEGIN
RETURN @p_value+‘-‘+ ‘W’
END
Go
Print ‘Without SchemaBinding Update Start:’+convert(varchar,GetDate(),113)
Go

Update dbo.tblItems
Set ItemName=dbo.SetValueWithoutSchemaBinding(ItemName)
Go

Print ‘Without SchemaBinding Update Finish:’+convert(varchar,GetDate(),113)
Go

Print ‘With SchemaBinding Update Start:’+convert(varchar,GetDate(),113)
Go

Update dbo.tblItems
Set ItemName=dbo.SetValueWithSchemaBinding(ItemName)
Go

Print ‘With SchemaBinding Update Finish:’+convert(varchar,GetDate(),113)
Go

Following is the output which shows 50% improvements (4 seconds to 2 seconds)

Inserting 100000 rows-Start:03 May 2007 00:13:41:670

Inserting 100000 rows-Finish:03 May 2007 00:14:26:590

Without SchemaBinding Update Start:03 May 2007 00:14:26:640

Without SchemaBinding Update Finish:03 May 2007 00:14:30:843

With SchemaBinding Update Start:03 May 2007 00:14:30:843

With SchemaBinding Update Finish:03 May 2007 00:14:32:340

Advertisements

Leave a Comment »

No comments yet.

RSS feed for comments on this post. TrackBack URI

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

Blog at WordPress.com.

%d bloggers like this: