October 3, 2013 at 7:05 am
Afternoon all,
Looking for a bit of advice on something I am struggling to explain. I have 3 functions, 2 of which are examples provided by Adam Machanic in a useful post he did on Scalar Functions vs Inline Functions. The functions use AdventureWorks and are as follows:
------------------------------------------------------
FUNCTION 1 - Inline Function 1:
CREATE FUNCTION [dbo].[GetMaxProductQty_Inline_Test1]
(
@ProductId INT
)
RETURNS TABLE
AS
RETURN
(
SELECT MAX(sod.OrderQty) AS maxqty
FROM Sales.SalesOrderDetail sod
WHERE sod.ProductId = @ProductId
)
FUNCTION 2 - Inline Function 2:
CREATE FUNCTION GetMaxProductQty_Inline_Test2
(
@ProductId INT
)
RETURNS @test-2 TABLE (MaxQty INT)
AS
BEGIN
DECLARE @MaxQty INT
SELECT @MaxQty =
(SELECT MAX(sod.OrderQty) AS maxqty
FROM Sales.SalesOrderDetail sod
WHERE sod.ProductId = @ProductId)
INSERT INTO @test-2 (MaxQty) VALUES (@MaxQty)
RETURN
END
FUNCTION 3 - Scalar Function:
CREATE FUNCTION GetMaxProductQty_Scalar_Test1
(
@ProductId INT
)
RETURNS INT
AS
BEGIN
DECLARE @maxQty INT
SELECT @maxQty = MAX(sod.OrderQty)
FROM Sales.SalesOrderDetail sod
WHERE sod.ProductId = @ProductId
RETURN (@maxQty)
END
------------------------------------------------------
I used this to give people an easy to understand example with the implications of a Scalar Functions vs Inline Function when they are both setup to return a similar results set. Inline Function 1 vs Scalar Function 1 highlighted what Adam described in his blog post in that the Inline Function was 288 times quicker and did 1200 (ish) Reads vs 365,000 (ish) Reads of the Scalar Function, and consumed vastly less CPU and in the process, allowed an optimised Execution Plan to be generated detailing exactly what was happening, rather than the Black Box Approach of the Scalar Function.
However, I set about re-writing the Inline Function to try and utilise parameters to return as a Table, which spawned Inline Function 2...
This function when used in exactly the same way as Inline Function 1, allowed SQL to generate a plan, but in reality still did a similar amount of Reads to the Scalar Function, only this time it was visible as to what was going on under the covers and what I deem to be the culprit which was a Nested Loop, which was cycling through the results in a similar way to the Scalar Function with a Row by Row Cursor like approach which was just as bad on performance, only more visible through the Execution Plan.
What I am struggling to understand is why Inline Function 1 is so superior to Inline Function 2 when they both run Inline with the query and they both allow SQL to generate a useful Execution Plan of what is going on behind the scenes. The obvious answer is the Nested Loop, but I am looking for more detail than this if possible. The SQL used to execute both these queries is as follows:
------------------------------------------------------
-- Inline Function 1 --
SELECT
ProductId,
(
SELECT MaxQty
FROM dbo.GetMaxProductQty_Inline_Test1(ProductId)
) MaxQty
FROM Production.Product
ORDER BY ProductId
-- Inline Function 2 --
SELECT
ProductId,
(
SELECT MaxQty
FROM dbo.GetMaxProductQty_Inline_Test2(ProductId)
) MaxQty
FROM Production.Product
ORDER BY ProductID
------------------------------------------------------
Any advice on this would be massively appreciated.
Cheers
October 3, 2013 at 7:25 am
Your "inline" function #2 is basically the same thing as a scalar function. It is multiple line function which means it behaves the same way. In fact, many time a multiline table function will perform even worse than a scalar function. In essence your function #2 is no longer an ITVF, it is now a MSTVF (multi statement table valued function).
Check out this post which does a great job explaining the differences. Make sure you read the comments to because there is another great article linked to there.
http://www.sqlservercentral.com/blogs/discussionofsqlserver/2012/02/15/comparing-inline-and-multistatement-table-valued-functions/[/url]
_______________________________________________________________
Need help? Help us help you.
Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.
Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.
Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/
October 3, 2013 at 7:27 am
Just so you know, Function2 is NOT an iTVF (Inline Table Valued Function). Rather, it's an mTFV (Multiline Table Valued Function) and those can be as bad or worse than a Scalar Function. I can't tell because you didn't list the final modified code for function 2 but if it still contains the table definition and the BEGIN/END, then it's still an mTVF and will still perform poorly as before.
--Jeff Moden
Change is inevitable... Change for the better is not.
October 3, 2013 at 7:57 am
Cheers guys.
The final code does include a Begin/End as part of the Table Valued Function so will be the same as you describe.
I will use this going forward, thanks once again.
October 3, 2013 at 6:12 pm
Jeff Moden (10/3/2013)
Rather, it's an mTFV (Multiline Table Valued Function) and those can be as bad or worse than a Scalar Function.
They can?
Not that I'm a disbeliever of course. It's just that usually when you make a statement like that you've got something in your back pocket to prove it.
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
October 3, 2013 at 8:55 pm
dwain.c (10/3/2013)
Jeff Moden (10/3/2013)
Rather, it's an mTFV (Multiline Table Valued Function) and those can be as bad or worse than a Scalar Function.They can?
Not that I'm a disbeliever of course. It's just that usually when you make a statement like that you've got something in your back pocket to prove it.
I 've been busy and just didn't have the time to prove the point. Of course, you're correct. People shouldn't make claims of performance without proof in the code.
With that in mind, here's code to create a test table, and mTVF, and an equivalent iTVF (equivalent in function)...
--===== Do these tests in a nice, safe place that everyone has.
USE tempdb
;
--===== Create and populate a super simple test table.
SELECT TOP 1000
SomeInt = IDENTITY(INT,1,1)
INTO dbo.TestTable
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
GO
--===== Create the mTVF to create a times table from 1 to 1000 for the @Multiplier
CREATE FUNCTION dbo.mTVF
(@Multiplier INT)
RETURNS @Result TABLE (Multiplican INT, Multiplier INT, Product INT)
WITH SCHEMABINDING AS
BEGIN
INSERT INTO @Result
(Multiplican, Multiplier, Product)
SELECT Multiplican = SomeInt
,Multiplier = @Multiplier
,Product = SomeInt * @Multiplier
FROM dbo.TestTable
;
RETURN
;
END
;
GO
--===== Create the iTVF to create a times table from 1 to 1000 for the @Multiplier
CREATE FUNCTION dbo.iTVF
(@Multiplier INT)
RETURNS TABLE WITH SCHEMABINDING AS
RETURN
SELECT Multiplican = SomeInt
,Multiplier = @Multiplier
,Product = SomeInt * @Multiplier
FROM dbo.TestTable
;
GO
Here's the code I used to test the functions without SQL Profiler running. The output has been directed to variables to take display times out of the picture. Each run produces a million row vertical "Times Table" based on 1000 * 1000 and each code example is executed 3 times. I primed the pump by running this code once and then turned on SQL Profiler to measure the performance.
--===== Test the mTVF for perfomance in it's own batch
DECLARE @Bitbucket1 INT
,@Bitbucket2 INT
,@Bitbucket3 INT
;
SELECT @Bitbucket1 = mult.Multiplican
,@Bitbucket2 = mult.Multiplier
,@Bitbucket3 = mult.Product
FROM dbo.TestTable tt
CROSS APPLY dbo.mTVF(tt.SomeInt) mult
;
GO 3
--===== Test the iTVF for perfomance in it's own batch
DECLARE @Bitbucket1 INT
,@Bitbucket2 INT
,@Bitbucket3 INT
;
SELECT @Bitbucket1 = mult.Multiplican
,@Bitbucket2 = mult.Multiplier
,@Bitbucket3 = mult.Product
FROM dbo.TestTable tt
CROSS APPLY dbo.iTVF(tt.SomeInt) mult
;
GO 3
Here are the results from profiler. Like I said, mTVF's can be as bad as SF's when it comes to performance. From here, it looks like the iTVF runs an average of 11.8 times faster than the mTVF and uses a whole lot less resources.
--Jeff Moden
Change is inevitable... Change for the better is not.
October 3, 2013 at 10:12 pm
The magnitude of the difference in your profiler trace does suggest that mTVFs could be in the same range as SFs.
Thanks for taking the time on it.
My thought question: Have you ever been told that your query runs too fast?
My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.
Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
Since random numbers are too important to be left to chance, let's generate some![/url]
Learn to understand recursive CTEs by example.[/url]
[url url=http://www.sqlservercentral.com/articles/St
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply