Query Help

  • I've a table like below:

    CREATE TABLE #Emp

    ( Emp char(6), UplineEmp char(6), Lvl tinyint) ;

    insert #Emp ([Emp], [UplineEmp], Lvl)

    values

    ('209156' ,'003033' ,17)

    , ('209156' ,'152870' ,16)

    , ('209156' ,'147013' ,15)

    , ('209156' ,'209156' ,5 )

    /*******/

    , ('211840' ,'003033' ,17)

    , ('211840' ,'033616' ,15)

    , ('211840' ,'211627' ,7 )

    , ('211840' ,'211840' ,5 ) ;

    Result set should be:

    CREATE TABLE #AR

    (

    AgtNum varchar(20), DirectUpline Varchar(20),

    Lvl0 Varchar(20), Lvl1 Varchar(20)

    , Lvl2 Varchar(20),Lvl3 Varchar(20)

    , Lvl4 Varchar(20), Lvl5 Varchar(20)

    )

    INSERT #AR

    VALUES ('209156', '147013', '003033', '152870','147013',NULL,NULL,NULL)

    , ('211840', '211627', '003033', '033616','211627',NULL,NULL,NULL)

    SELECT * FROM #AR

    Employees have a row with themselves as an upline, so the direct upline is an employee one level up (using the Lvl column).

    Lvl0 column in result set is the top level employee, all other level columns should be populated respectively. NULL should be shown when hierarchy is ragged.

    Can you please help me with a decently running query, I could write only a cursor and it's slow with over 2million rows I have.

    Appreciate your time.

  • Nice job posting ddl and sample data along with desired output. However it is totally unclear what the logic should be here.

    This looks somewhat like an adjacency list except it is recursive and incomplete. What is the logic of having an Emp and UplineEmp be the same? What is the logic that determines DirectUpline? What about Lvl0 - Lvl5?

    _______________________________________________________________

    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/

  • This resolves the simple case you've given us, however I suspect it may not be the solution to your problem.

    ;WITH CTE AS (

    SELECT AgentNum

    ,Lvl0=MAX(CASE n WHEN 1 THEN UplineEmp END)

    ,Lvl1=MAX(CASE n WHEN 2 THEN UplineEmp END)

    ,Lvl2=MAX(CASE n WHEN 3 THEN UplineEmp END)

    ,Lvl3=MAX(CASE n WHEN 4 THEN UplineEmp END)

    ,Lvl4=MAX(CASE n WHEN 5 THEN UplineEmp END)

    ,Lvl5=MAX(CASE n WHEN 6 THEN UplineEmp END)

    FROM (

    SELECT AgentNum=Emp, UplineEmp, Lvl

    ,n=CASE WHEN Emp=UplineEmp THEN 0

    ELSE ROW_NUMBER() OVER (PARTITION BY Emp ORDER BY Lvl DESC) END

    FROM #Emp) a

    GROUP BY AgentNum)

    SELECT AgentNum

    ,DirectUpline=COALESCE(Lvl5, Lvl4, Lvl3, Lvl2, Lvl1, Lvl0)

    ,Lvl0, Lvl1, Lvl2, Lvl3, Lvl4, Lvl5

    FROM CTE

    It won't work if you need to resolve multiple levels of hiearchy but you haven't given us any data or expected results for a case like that.

    If you give us more, perhaps we can take it to the next level.


    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

  • Thanks All.

    Dwain - Query works for me, but i don't think i understand what you mean by resolving multiple levels of hierarchy - my ignorance. I always have a predefined number of levels in the hierarchy. So, I'm thinking it should always work.

  • UnionAll (11/30/2012)


    Thanks All.

    Dwain - Query works for me, but i don't think i understand what you mean by resolving multiple levels of hierarchy - my ignorance. I always have a predefined number of levels in the hierarchy. So, I'm thinking it should always work.

    If it works then it works. I think earlier posters didn't recognize that hiearchy depth was fixed in your sample data so that is why I posted what I did to show that no recursion was needed (if not additional depth applies).


    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

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

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