Dynamic Case Statement

  • Hello all, I'm having some issues with a query I have which includes a dynamic case statement. I realize having a dynamic case statement is not the best practice but I'm having trouble understanding why it doesn't return any results.

    Basically what's happening is this:

    DECLARE @EMP VARCHAR(MAX) = 'EMP1'

    DECLARE @MGR VARCHAR(MAX) = ''''+'MGR1'+'''' + ',' + ''''+'MGR2'+''''

    DECLARE @FILTER VARCHAR(MAX) = @MGR

    DECLARE @VIEW INT = 1

    SELECT * FROM dbo.EMPLOYEE AS EMP WHERE EMP.MGR IN (@FILTER)

    In this statement I return 0 results

    When I select the parameter values it returns:

    SELECT @FILTER

    RETURNS: 'MGR1','MGR2'

    Of course if I hard code the return results it returns data

    SELECT * FROM dbo.EMPLOYEE AS EMP WHERE EMP.MGR IN ('MGR1','MGR2')

    And if I limit the parameter to just one name it returns data fine

    DECLARE @MGR VARCHAR(MAX) = ''''+'MGR1'+''''

    SELECT * FROM dbo.EMPLOYEE AS EMP WHERE EMP.MGR IN (@FILTER)

    I also tried placing the results into a table but that did not work either

    DECLARE @FILTERS TABLE (Name NVARCHAR(MAX))

    INSERT INTO @FILTERS

    SELECT @FILTER

    SELECT * FROM dbo.EMPLOYEE AS EMP WHERE EMP.MGR IN (SELECT Name FROM @FILTER)

    Just having trouble understanding what is causing this to not return. Any insight would be appreciated

  • I believe you'll need to do something like this:

    DECLARE @FILTERS TABLE (Name NVARCHAR(MAX))

    INSERT INTO @FILTERS

    SELECT 'MGR1' UNION ALL SELECT 'MGR2'

    SELECT *

    FROM dbo.EMPLOYEE AS EMP

    WHERE EMP.MGR IN (SELECT Name FROM @FILTER)


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • The only issue is I don't know the number of Manager names to be selected as it will be based on user defined parameter

  • Try this then:

    DECLARE @FILTER VARCHAR(8000) = 'MGR1,MGR2'

    SELECT *

    FROM dbo.EMPLOYEE AS EMP

    WHERE EMP.MGR IN (SELECT Item FROM DelimitedSplit8K(@FILTER, ','))

    You can find the DelimitedSplit8K FUNCTION here:

    Tally OH! An Improved SQL 8K “CSV Splitter” Function[/url]

    Note that DelimitedSplit8K is designed to work with VARCHAR(8000) and not NVARCHAR(MAX) as in your original code. You'd need to either modify it to use that data type (not recommended by the author) or use a different delimited string splitter. Unless you need the UNICODE characters, it's pretty unlikely the user would enter a 2GB parameter string.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    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

  • I don't currently have sufficient permissions to create functions but I might be able to get this in front of someone who can add this. Thanks for the article

Viewing 5 posts - 1 through 4 (of 4 total)

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