SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


UDF Performance When Used As A "Macro"


UDF Performance When Used As A "Macro"

Author
Message
Todd Young-359443
Todd Young-359443
SSC Journeyman
SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)

Group: General Forum Members
Points: 97 Visits: 183
My group is having a discussion as to performance hits when a UDF is used as a macro -
IE it accesses no tables, is passed no rows. Some simple logic and a calculation on a date/time
value.

Here is an abbreviated version of the code (removed check for DST):



Create FUNCTION fnAdjustDateTime (@date datetime, @timezone int)

RETURNS datetime
AS
BEGIN
--
-- declare variables
--
declare @dst bit
declare @offset int
declare @result datetime
--
-- Get the timezone data we will need
--
if @timezone = 1
Select @offset = -5, @dst = 1
else if @timezone = 2
Select @offset = -6, @dst = 1
else if @timezone = 3
Select @offset = -7, @dst = 1
else if @timezone = 4
Select @offset = -8, @dst = 1
else if @timezone = 5
Select @offset = -10, @dst = 0
else if @timezone = 6
Select @offset = -9, @dst = 1
else if @timezone = 7
Select @offset = -4, @dst = 0
else if @timezone = 8
Select @offset = -7, @dst = 0
else if @timezone = 9
Select @offset = -11, @dst = 0
else
Select @offset = -6, @dst = 1
--
-- Set result now
--
set @result = DateAdd(hh,@offset,@date)

return @result




Could someone please provide some insight on this as well a a logical explanation ??

Thanks ...

Todd
Lowell
Lowell
SSC Guru
SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)SSC Guru (75K reputation)

Group: General Forum Members
Points: 75077 Visits: 40985
well, ideally, your scalar UDF can be converted to an inline table funciton instead.

Create FUNCTION fnAdjustDateTime_itv (@date datetime, @timezone int)

RETURNS table
AS
RETURN
SELECT DateAdd(hh,CASE
WHEN @timezone = 1 THEN -5
WHEN @timezone = 2 THEN -6
WHEN @timezone = 3 THEN -7
WHEN @timezone = 4 THEN -8
WHEN @timezone = 5 THEN -10
WHEN @timezone = 6 THEN -9
WHEN @timezone = 7 THEN -4
WHEN @timezone = 8 THEN -7
WHEN @timezone = 9 THEN -11
END,
@date) As ResultDate
GO
Create FUNCTION fnAdjustDateTime (@date datetime, @timezone int)

RETURNS datetime
AS
BEGIN
--
-- declare variables
--
declare @dst bit
declare @offset int
declare @result datetime
--
-- Get the timezone data we will need
--
if @timezone = 1
Select @offset = -5, @dst = 1
else if @timezone = 2
Select @offset = -6, @dst = 1
else if @timezone = 3
Select @offset = -7, @dst = 1
else if @timezone = 4
Select @offset = -8, @dst = 1
else if @timezone = 5
Select @offset = -10, @dst = 0
else if @timezone = 6
Select @offset = -9, @dst = 1
else if @timezone = 7
Select @offset = -4, @dst = 0
else if @timezone = 8
Select @offset = -7, @dst = 0
else if @timezone = 9
Select @offset = -11, @dst = 0
else
Select @offset = -6, @dst = 1
--
-- Set result now
--
set @result = DateAdd(hh,@offset,@date)

return @result
END
GO



then the calling code gets changed to this:


select name, dbo.fnAdjustDateTime(create_date,1) from sys.objects

select name, fn.*
from sys.objects
CROSS APPLY dbo.fnAdjustDateTime_itv(create_date,1) fn



if you include actual execution palns and compare them, you will start seeing hwo the ITVF version is better; scalar functions usualyl get called once per row,
where an ITVF is treated like a set based operation

on this small dataset of using sys.objects, my results were the same; but on bigger datasets, the ITVF will be much more efficient.

Lowell
--help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)

Group: General Forum Members
Points: 222294 Visits: 42003
Todd Young-359443 (10/12/2012)
My group is having a discussion as to performance hits when a UDF is used as a macro -
IE it accesses no tables, is passed no rows. Some simple logic and a calculation on a date/time
value.


To add to what Lowell has posted, "One test is worth a thousand expert opinions". Please see the following article for what a difference an "iSF" can make over such a Scalar UDF.
http://www.sqlservercentral.com/articles/T-SQL/91724/

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
Todd Young-359443
Todd Young-359443
SSC Journeyman
SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)SSC Journeyman (97 reputation)

Group: General Forum Members
Points: 97 Visits: 183
I was able to work at home this weekend and found the answer. When calling
at UDF that does not access any database table and is used more like a macro,
the performance hit is negligible.

The raw difference in a 20,000 row dataset was 200 milliseconds. When I removed
the overhead of the three DateAdd functions it dropped to 100 milliseconds.

We are keeping the function in production and have dropped this as a candidate
for optimization.
Jeff Moden
Jeff Moden
SSC Guru
SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)SSC Guru (222K reputation)

Group: General Forum Members
Points: 222294 Visits: 42003
Todd Young-359443 (10/15/2012)

I was able to work at home this weekend and found the answer. When calling
at UDF that does not access any database table and is used more like a macro,
the performance hit is negligible.

The raw difference in a 20,000 row dataset was 200 milliseconds. When I removed
the overhead of the three DateAdd functions it dropped to 100 milliseconds.

We are keeping the function in production and have dropped this as a candidate
for optimization.

I guess it really depends on what you call "negligible". You're talking about a function that runs twice as fast and that's not "negligible" especially when you consider that you're only working with 20,000 rows.

"Mind the pennies and the dollars will take care of themselves." ;-)

--Jeff Moden

RBAR is pronounced ree-bar and is a Modenism for Row-By-Agonizing-Row.
First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column.
If you think its expensive to hire a professional to do the job, wait until you hire an amateur. -- Red Adair

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
TheSQLGuru
TheSQLGuru
SSC-Dedicated
SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)SSC-Dedicated (33K reputation)

Group: General Forum Members
Points: 33411 Visits: 8682
Todd Young-359443 (10/15/2012)

I was able to work at home this weekend and found the answer. When calling
at UDF that does not access any database table and is used more like a macro,
the performance hit is negligible.

The raw difference in a 20,000 row dataset was 200 milliseconds. When I removed
the overhead of the three DateAdd functions it dropped to 100 milliseconds.

We are keeping the function in production and have dropped this as a candidate
for optimization.



You are fooling yourself. There are MANY reasons why UDFs are bad (see my chapter in the SQL Server MVP Deep Dives 2 book titled Death By UDF and my SQL Rally 2012 session of the same name). Depending on how this UDF gets used it could prevent the optimizer from getting accurate statistics on the query and thus lead to a disastrously bad query plan. And did you know that UDFs also void the use of parallelism? Lots of other potential issues come with them.

Best,
Kevin G. Boles
SQL Server Consultant
SQL MVP 2007-2012
TheSQLGuru on googles mail service
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search