SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Help Required to build Sql Query


Help Required to build Sql Query

Author
Message
nag_arjun123
nag_arjun123
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 43
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
== ====== ========
1 b1 0
2 b2 1
3 b3 1
4 b4 2
5 b5 4
6 b6 3
7 b7 0

Table: Users id- primary key
id, name
1 u1
2 u2

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

Table: users_workgroup (uid,wgid) - primary key
uid, wgid
=== =====
1 1
2 2
2 3

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?
Chris Harshman
Chris Harshman
SSChampion
SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)SSChampion (10K reputation)

Group: General Forum Members
Points: 10428 Visits: 4631
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 = @UserID
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.
nag_arjun123
nag_arjun123
Forum Newbie
Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)Forum Newbie (4 reputation)

Group: General Forum Members
Points: 4 Visits: 43
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
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search