Home Forums SQL Server 2008 T-SQL (SS2K8) Need Help on User Tree Hierarchy with Addition/Deletion Option RE: Need Help on User Tree Hierarchy with Addition/Deletion Option

  • This should do the trick, but with out example data it might be off the mark, luckily I was at a loose end for an hour or to and pus some data together based on the sample.

    DECLARE @sys_user TABLE

    (UserId bigint

    ,FRST_NM varchar(100)

    ,LST_NM varchar(100)

    ,APROV_ID bigint)

    Insert into @sys_user

    Select 800000000, 'Dave', 'Smith', NULL

    UNION Select 810000000, 'Michael', 'Chak',800000000

    UNION Select 811000000, 'David', 'Boon',810000000

    UNION Select 811100000, 'Glen','Macgrath',811000000

    UNION Select 811110000, 'Alex', 'Boon',811100000

    UNION Select 811111000, 'Jim', 'Foley',811111000

    UNION Select 821000000,'Stephan', '',800000000

    DECLARE @userid BIGINT=800000000

    select * from @sys_user

    ;With submenu (UserId,Name,APROV_ID,lvl)

    AS

    (

    Select UserId, FRST_NM + ' '+LST_NM as Name,APROV_ID, 0 lvl

    From @sys_user

    Where UserId=@UserId

    Union ALL Select

    su.UserId

    ,su.FRST_NM + ' '+su.LST_NM

    ,su.APROV_ID

    ,sm.lvl+1

    From @sys_user su

    Join submenu sm ON su.APROV_ID=sm.UserId

    )

    Select SPACE(lvl*2)+STR(UserID) + '|| '+Name,lvl

    From submenu

    Order by UserId

    PS: I see you're a bit of a cricket fan, hope you're enjoying the T20.

    _________________________________________________________________________
    SSC Guide to Posting and Best Practices