• 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


    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.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)