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


Parent-Child But Not All Have Children...?


Parent-Child But Not All Have Children...?

Author
Message
brian.battles
brian.battles
Grasshopper
Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)

Group: General Forum Members
Points: 17 Visits: 35
Here's a tricky one:

I have to show values for each of our customers. Data comes from a table something like this:

Customer_id Value

1 100
2 150
3 1000
4 300
.
.
.
10 120
11 150
12 1000
13 200



etc



Most customers just have one account, but some have multiple "sibling" (or "child") accounts. Those with "children" are mapped in a table like:

Customer_id (Parent) Child_id
1 10
1 11
1 12
2 13
3 14
3 15
5 16



etc

What I need to do is display a list showing all accounts and their own values, but if an account is a Parent it needs to show the value of itself and all its children added together:

Customer_id Value

1 1370 (100 + 120 + 150 + 1000
2 350 (150 + 200)
3 1000
.
.
.
10 120
11 150
12 1000
13 200



If a Parent doesn't exist in the Parent-Child mapping table all we show is its own value

Customer_id Vaue
4 300

This seems like it requires a convoluted query!

Any ideas?

Thanx!
Want a cool Sig
Want a cool Sig
SSC-Addicted
SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)SSC-Addicted (414 reputation)

Group: General Forum Members
Points: 414 Visits: 705
Try looking at recursive CTE or adjacency model to start. There's plenty of good articles on SSC on what you want to do.

[Edit]
Oops yeah that works. Didn't read the req. clearly, I thought you wanted to append the values like a string. Summing it is a lot easier... Smile

---------------------------------------------------------------
Mike Hahn - MCSomething someday:-)
Right way to ask for help!!
http://www.sqlservercentral.com/articles/Best+Practices/61537/
I post so I can see my avatar Hehe
I want a personal webpage Cool
I want to win the lotto :-D
I want a gf like Tiffa w00t Oh wait I'm married!:-D
Kingston Dhasian
Kingston Dhasian
Hall of Fame
Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)Hall of Fame (3.7K reputation)

Group: General Forum Members
Points: 3693 Visits: 5180
Something like this

DECLARE   @tbl_Customer TABLE
(
Customer_id INT,
Value NUMERIC(18,2)
)

DECLARE @tbl_Relation TABLE
(
Customer_id INT,
Child_id INT
)

INSERT @tbl_Customer
SELECT 1, 100 UNION ALL
SELECT 2, 150 UNION ALL
SELECT 3, 1000 UNION ALL
SELECT 4, 300 UNION ALL
SELECT 10, 120 UNION ALL
SELECT 11, 150 UNION ALL
SELECT 12, 1000 UNION ALL
SELECT 13, 200

INSERT @tbl_Relation
SELECT 1, 10 UNION ALL
SELECT 1, 11 UNION ALL
SELECT 1, 12 UNION ALL
SELECT 2, 13 UNION ALL
SELECT 3, 14 UNION ALL
SELECT 3, 15 UNION ALL
SELECT 5, 16

SELECT C.Customer_id, C.Value + COALESCE( SUM( CR.Value ), 0 ) AS Value
FROM @tbl_Customer AS C
LEFT OUTER JOIN @tbl_Relation AS R ON C.Customer_id = R.Customer_id
LEFT OUTER JOIN @tbl_Customer AS CR ON R.Child_id = CR.Customer_id
GROUP BY C.Customer_id, C.Value
ORDER BY C.Customer_id




Kingston Dhasian

How to post data/code on a forum to get the best help - Jeff Moden
http://www.sqlservercentral.com/articles/Best+Practices/61537/
brian.battles
brian.battles
Grasshopper
Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)Grasshopper (17 reputation)

Group: General Forum Members
Points: 17 Visits: 35
Thanks, Kingston, I'll give that a try...
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