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


Performace Improvement in Table Valued Function


Performace Improvement in Table Valued Function

Author
Message
gordon.davis
gordon.davis
SSC Rookie
SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)SSC Rookie (30 reputation)

Group: General Forum Members
Points: 30 Visits: 60
Hi Guys,
Could you Please help me to improve the function Performance.This Function is used in allmost all procedures in my application.
Execution statement
SELECT * FROM dbo.fn_Child_09242012(1007538)
--2320006 rows it took almost 55 sec

Sql query Inside the Function



CREATE FUNCTION dbo.fn_Child_09242012
(
@strID int
)
RETURNS @table TABLE (ID int)
AS
BEGIN
Declare @ind int
Set @ind=(Select REP From Table1 where ID=@strID)
If @ind=1
BEGIN
INSERT INTO @table(ID) SELECT @strID

INSERT INTO @table(ID)
SELECT ID
FROM Table2 WITH(NOLOCK)
WHERE ParentID in (Select * From dbo.fn_getOrgIDList(@strID))
END
ELSE
BEGIN
INSERT INTO @table(ID)
SELECT ID
FROM Table2 WITH(NOLOCK)
WHERE ParentID = @strID
END
Return
END
GilaMonster
GilaMonster
SSC Guru
SSC Guru (228K reputation)SSC Guru (228K reputation)SSC Guru (228K reputation)SSC Guru (228K reputation)SSC Guru (228K reputation)SSC Guru (228K reputation)SSC Guru (228K reputation)SSC Guru (228K reputation)

Group: General Forum Members
Points: 228607 Visits: 46342
55 sec to fetch, process and display 2.3 million rows isn't all that bad.

It's not necessarily that function that's the problem, it's the usage of that function in complex queries (ie anything with a join and/or a where). Because of the table variable, SQL can't get a cardinality estimate for the function and is going to assume 1 row. Since it actually returns 2.3 million, that's a really bad estimate and it's very likely to cause seriously bad execution plans for other queries.

I assume replacing that with a stored proc and temp table is out of the question?

Is dbo.fn_getOrgIDList(@strID) also a multi-statement table valued function?

p.s. http://blogs.msdn.com/b/davidlean/archive/2009/04/06/sql-server-nolock-hint-other-poor-ideas.aspx

Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass


Jason-299789
Jason-299789
SSCertifiable
SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)SSCertifiable (5.1K reputation)

Group: General Forum Members
Points: 5071 Visits: 3232
Assuming that the fn_GetOrgIdList returns a table then surely You're better doing something.

INSERT INTO @table(ID)
SELECT Table2.ID
FROM Table2 WITH(NOLOCK)
JOIN dbo.fn_GetOrgIdList(@StrId) org on org.<col>=Table2.ParentId



You might get an optimisation from also doing

IF (Select REP from Table1 Where Id=@strId)=1
BEGIN

END


Those are just a couple of ideas, but without knowing what fn_getOrfIdList(@var) does its difficult to advise.

_________________________________________________________________________
SSC Guide to Posting and Best Practices
ChrisM@Work
ChrisM@Work
SSC-Forever
SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)SSC-Forever (42K reputation)

Group: General Forum Members
Points: 42184 Visits: 20012
Inline tvf's would get around the cardinality issues Gail mentions. Something like this:

DECLARE @strID int 

SELECT ID
FROM Table1
WHERE ID = @strID AND REP = 1
UNION ALL
SELECT ID
FROM Table2 WITH(NOLOCK)
CROSS APPLY (SELECT REP FROM Table1 WHERE ID = @strID) x
WHERE (x.REP <> 1 AND ParentID = @strID)
OR (x.REP = 1 AND ParentID IN (SELECT * FROM dbo.fn_getOrgIDList(@strID)) )



...where dbo.fn_getOrgIDList would have to be similarly tweaked.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Grant Fritchey
Grant Fritchey
SSC Guru
SSC Guru (99K reputation)SSC Guru (99K reputation)SSC Guru (99K reputation)SSC Guru (99K reputation)SSC Guru (99K reputation)SSC Guru (99K reputation)SSC Guru (99K reputation)SSC Guru (99K reputation)

Group: General Forum Members
Points: 99635 Visits: 33014
You've got nested functions and you're accessing large amounts of data? That's a major design flaw. The only way to improve performance is back out of the use of multi-statement table valued functions and start addressing the T-SQL directly. The inline functions might be a good idea, but don't nest them. Otherwise, regular T-SQL queries are usually the best approach. If you really need to break down the code, which is a valid approach at times, then use temporary tables because they will provide statistics making queries that JOIN them or search against them more efficient.

Also, one suggestion involved the NO_LOCK hint. I'm very wary of hints in general, but the NO_LOCK hint in particular is especially dangerous. Understand it thoroughly before you apply it.

----------------------------------------------------
The credit belongs to the man who is actually in the arena, whose face is marred by dust and sweat and blood...
Theodore Roosevelt

The Scary DBA
Author of: SQL Server Query Performance Tuning and SQL Server Execution Plans
Product Evangelist for Red Gate Software
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