Dynamic Filter and Order By

  • Hi,

    I'm doing some testing with dynamic filtering and order by clause.

    I'm comparing dynamic SQL vs using the CASE statement...

    DECLARE @FilterName NVARCHAR(100) = 'M%'

    DECLARE @FilterSalary FLOAT = 3000

    DECLARE @OrderField INT = 0 --0 empname, 1 salary, 2 - empid

    DECLARE @Query NVARCHAR(500)

    DECLARE @params NVARCHAR(500)

    SET @Query = 'SELECT empid, empname, salary FROM dbo.Employees WHERE 1 = 1'

    SET @params = '@FilterNameIn NVARCHAR(100), @FilterSalaryIn FLOAT'

    IF LEN(@FilterName) > 0

    SET @Query = @Query + ' AND empname LIKE @FilterNameIn'

    IF LEN(@FilterSalary) > 0

    SET @Query = @Query + ' AND salary > @FilterSalaryIn'

    IF @OrderField = 0

    SET @Query = @Query + ' ORDER BY empname'

    IF @OrderField = 1

    SET @Query = @Query + ' ORDER BY salary'

    IF @OrderField = 2

    SET @Query = @Query + ' ORDER BY empid'

    EXEC sp_executesql @query, @params, @FilterNameIn = @FilterName, @FilterSalaryIn = @FilterSalary

    SELECT empid, empname, salary FROM dbo.Employees WHERE

    empname LIKE CASE WHEN LEN(@FilterName) > 0 THEN @FilterName ELSE empname END

    AND

    salary >= ISNULL(@FilterSalary, 0)

    ORDER BY

    CASE WHEN @OrderField = 0 THEN empname END,

    CASE WHEN @OrderField = 1 THEN salary END,

    CASE WHEN @OrderField = 2 THEN empid END

    Initially I tried

    ORDER BY

    CASE

    WHEN @OrderField = 0 THEN empname

    WHEN @OrderField = 1 THEN salary

    WHEN @OrderField = 2 THEN empid

    END

    To order by only one column but since the fields have different data types SQL gave an error. I could do a CAST but salary as NVARCHAR doesn't give good results... So I used the 3 columns sort.....

    In both cases the execution plan is very similar, the CASE statement has a Compute Scalar with 0% (from the CASE statement)...

    But if I order by the 3rd column ( = 2) to non dynamic statement, according to execution plan comparing both, is much "heavier" since it orders by 2 NULL columns and only then by the desired column....

    Is this a case where Dynamic SQL can be used, where it's better than "regular" SQL statements?

    Thanks,

    Pedro



    If you need to work better, try working less...

  • You should read this article from Gail about catch all queries. http://sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/[/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/

  • Sean Lange (10/2/2012)


    You should read this article from Gail about catch all queries. http://sqlinthewild.co.za/index.php/2009/03/19/catch-all-queries/[/url]

    Thanks, I've read it and it answers my question...

    But is there a way of having a dynamic ORDER BY with CASE clause without having N order columns?!

    ORDER BY CASE WHEN @ordfld = 1 THEN MoneyField WHEN @ordfld = 2 THEN NameField END

    this raises an error.. it has to be written

    ORDER BY CASE WHEN @ordfld = 1 THEN MoneyField END, CASE WHEN @ordfld = 2 THEN NameField END

    which makes 3 order by clauses when I only want one, even if they can be NULL...

    Thanks,

    Pedro



    If you need to work better, try working less...

  • if you know where the column that you want to Order By, sits, you can do

    select

    col1

    ,col2

    ,col3

    from tablename

    order by 1

    this will order by the first column.

    change it to 'order by 2' to order by the second column

  • Thanks... using the column number isn't as much readable friendly as is the column name.... but it works fine 🙂

    Is there any problem using the column number besides risking adding a column to the query and messing the order and not being so friendly?!

    Thanks,

    Pedro



    If you need to work better, try working less...

  • PiMané (10/2/2012)


    Thanks... using the column number isn't as much readable friendly as is the column name.... but it works fine 🙂

    Is there any problem using the column number besides risking adding a column to the query and messing the order and not being so friendly?!

    Thanks,

    Pedro

    It will work but referring to columns by ordinal position is fraught with maintenance issues. You have already defined the problem. The query changes and the person making the change doesn't know or even think about the order by variable stuff going on.

    _______________________________________________________________

    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/

  • Thanks to all for the help..

    Pedro



    If you need to work better, try working less...

  • Hi,

    I just made a simple test... I build a dynamic SQL to execute and executed the same query directly in SMSS...

    Can anyone explain why the dynamic SQL is 46% of total time and the same query but "fixed" is 54%, as shown in the attachment..?!?!

    CREATE NONCLUSTERED INDEX [idx_Employees_003] ON [dbo].[Employees]

    (

    [empname] ASC,

    [salary] ASC

    );

    This is the index being used...

    If I use the "fixed" SQL but "guessing" the parameters, like this:

    SELECT empid, empname, salary FROM dbo.Employees WHERE empname >= CASE WHEN LEN(@FilterName) > 0 THEN @FilterName ELSE empname END AND salary >= ISNULL(@FilterSalary, 0)

    SQL suggests an index on salary including empid and empname..

    If instead of empname >= ... I use empname LIKE ..., on the dynamic SQL, it also suggests the index on salary and include empid and empname... Isn't LIKE as good as >= for index seeks?!?

    Thanks,

    Pedro



    If you need to work better, try working less...

  • ... Isn't LIKE as good as >= for index seeks?!?

    NO LIKE is not SARGable so you will get scans. It has to examine every row to determine if it is a match or not.

    _______________________________________________________________

    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/

  • Sean Lange (10/3/2012)


    NO LIKE is not SARGable so you will get scans. It has to examine every row to determine if it is a match or not.

    So a LIKE 'M%' is better replaced with a >= 'M' AND < 'N'..



    If you need to work better, try working less...

  • Sean Lange (10/3/2012)


    ... Isn't LIKE as good as >= for index seeks?!?

    NO LIKE is not SARGable so you will get scans. It has to examine every row to determine if it is a match or not.

    Actually LIKE is sargable when the pattern expression reduces to matching an initial substring, provided of course the pattern expression is unicode when the column is unicode and not unicode when the column is not unicode; so it doesn't prevent index scans.

    (I remember thisone because it's half of a weird inconsistency: using LIKE to match an initial substring is sargable, while using LEFT is not ;-))

    edit:spelling

    Tom

  • PiMané (10/3/2012)


    Sean Lange (10/3/2012)


    NO LIKE is not SARGable so you will get scans. It has to examine every row to determine if it is a match or not.

    So a LIKE 'M%' is better replaced with a >= 'M' AND < 'N'..

    No, that is wrong! LIKE 'M%' is SARGable, you don't need to replace it with such a mess

    However, LIKE '%M' is not SARGable!. But replacing it with comparison operators will be quite problematic :-D.

    If you really need the best possible performance for text searches like the above, there is SQL Server feature called Full Text Search. http://msdn.microsoft.com/en-us/library/ms142571.aspx

    It's designed for performing effective comprehensive text searches.

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • L' Eomot Inversé (10/4/2012)


    Sean Lange (10/3/2012)


    ... Isn't LIKE as good as >= for index seeks?!?

    NO LIKE is not SARGable so you will get scans. It has to examine every row to determine if it is a match or not.

    Actually LIKE is sargable when the pattern expression reduces to matching an initial substring, provided of course the pattern expression is unicode when the column is unicode and not unicode when the column is not unicode; so it doesn't prevent index scans.

    (I remember thisone because it's half of a weird inconsistency: using LIKE to match an initial substring is sargable, while using LEFT is not ;-))

    edit:spelling

    Thanks for the clarification Tom.

    _______________________________________________________________

    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/

  • Hi,

    Regarding Dynamic SQL....

    Instead of a SELECT suppose I have an UPDATE used on a SP.

    The SP receives 6 parameters: @RecordId, @Col1Value, @Col2Update, @Col2Value, @Col3Update, @Col3Value...

    Col1 is always updated but Col2 and Col3 are only updated if Col2Update and Col3Update are true (1).

    Should dynamic SQL be used here as well?

    I could write

    UPDATE table SET

    Col1 = @Col1Value,

    Col2 = CASE WHEN @Col2Update = 1 THEN @Col2Value ELSE Col2 END,

    Col3 = CASE WHEN @Col3Update = 1 THEN @Col3Value ELSE Col3 END

    WHERE Id = @RecordId

    but this would make Col2 and Col3 always be updated no matter what, even if the value is themselves...

    also it's possible to write:

    UPDATE table SET Col1 = @Col1Value WHERE Id = @RecordId

    IF @Col2Update = 1

    UPDATE table SET Col2 = @Col2Value WHERE Id = @RecordId

    ....

    This would make another seek and update row and if the table had an UPDATE trigger it would fire the trigger again...

    Back to the 1st case if there was also a trigger with the condition IF UPDATED(Col2) the condition would always be true...

    There also the long solution:

    IF @Col2Update = 1 AND @Col3Update = 1

    ....

    ELSE

    IF @Col2Update = 1

    ELSE

    .....

    IF @Col3Update = 1

    .....

    ELSE

    ...

    This is long and if necessary to add another column it would even longer... 2^[optional parameters]..

    So is dynamic SQL a good option for this case too?!

    Thanks,

    Pedro



    If you need to work better, try working less...

  • PiMané (10/4/2012)


    Regarding Dynamic SQL....

    Instead of a SELECT suppose I have an UPDATE used on a SP.

    The SP receives 6 parameters: @RecordId, @Col1Value, @Col2Update, @Col2Value, @Col3Update, @Col3Value...

    Col1 is always updated but Col2 and Col3 are only updated if Col2Update and Col3Update are true ....

    ....

    So is dynamic SQL a good option for this case too?!

    The trigger is going to be fired anyway, teh data engine is going to be invoked anyway, the update is going to be logged anyway, because col1 is alwys updated. So having the 2 case expressions in the update statement to generate updates that either do or don't update col2 and col3 doesn't generate any noticeable overhead, may even be cheaper in performance terms than building dynamic SQL.

    Of course if you have an IF UPDATED(col2) condition in the trigger that wants to know whether col2 was actually changed you have to write it differently, but that is trivial for your update statement (and supertrivial if id is a unique key).

    Tom

Viewing 15 posts - 1 through 15 (of 18 total)

You must be logged in to reply to this topic. Login to reply