Help Required to build Sql Query

  • Table: workgroup id - primary key

    id,name

    == ====

    1 w1

    2 w2

    3 w3

    Table: bizunit : id - primary key ; parent_id - foreignkey to same table column Id

    id, name, parent_id

    ================

    1b10

    2b21

    3b31

    4b42

    5b54

    6b63

    7b70

    Table: Users id- primary key

    id,name

    1u1

    2u2

    Table: workgroup_bizunit (wgid,bid) --> primary key

    wgid,bid

    =======

    22

    32

    23

    Table: users_workgroup (uid,wgid) - primary key

    uid,wgid

    ========

    11

    22

    23

    The above given are the table structure and having the sample data.

    Now , i have to construct a query based on these tables . could anyone help regarding this.

    The input parameter would be the User Id : Lets say I want the details of business units, workgroup which are associated to User Id - 2

    In the application The business units tree view structure would be like this

    --------------------------------------------------------------------------

    Business unit b2 is associated to workgroups w2,w3. And User Id 2 is associated to workgroups w2,w3.

    Business unit b3 is associated to workgroup w2.

    System

    |

    |________b2

    | |________b4

    | |________b5

    |

    |________b3

    |

    |________b6

    The Output Should be

    b2, w2

    b2, w3

    b3, w2

    b4, w2

    b4, w3

    b5, w2

    b5, w3

    b6, w2

    I want business units b4,b5 in the output because associated to its workgroup thru parent business unit b2.

    I want business units b6 in the output because associated to its workgroup thru parent business unit b3.

    To built the query i have to user common table expressions. Could anyone help

    to solve this query?

  • Yes, a recursive CTE solves this rather nicely:

    ;WITH WGBizTree (bid, bname, wgid, wgname) AS

    -- anchor part

    (SELECT wb.bid, b.name AS bname, wb.wgid, w.name AS wgname

    FROM users_workgroup uw

    INNER JOIN workgroup_bizunit wb ON uw.wgid = wb.wgid

    INNER JOIN bizunit b ON wb.bid = b.id

    INNER JOIN workgroup w ON wb.wgid = w.id

    WHERE uw.uid = @user-id

    UNION ALL

    -- recursive part

    SELECT b.id, b.name AS bname, bt.wgid, w.name AS wgname

    FROM WGBizTree bt

    INNER JOIN bizunit b ON bt.bid = b.parent_id

    INNER JOIN workgroup w ON bt.wgid = w.id)

    SELECT bname, wgname

    FROM WGBizTree

    ORDER BY bname, wgname

    The key is to have an anchor query that gets the business units directly associated to the workgroups that the specified user is in, then join itself back to the bizunit table by parent_id to get the children business units.

  • Hi Chris,

    Thanks, The query was working fine.

    Actually i am trying the query in single statement without using UNION ALL.

    So, because of that i could not able to get required output.

    Once thanks again, for giving me the Solution.

    Thank You,

    Regards,

    Nagarjun.T

Viewing 3 posts - 1 through 2 (of 2 total)

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