Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Parent-Child But Not All Have Children...? Expand / Collapse
Author
Message
Posted Friday, April 19, 2013 7:46 AM


Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, April 23, 2013 5:53 AM
Points: 9, 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!
Post #1444405
Posted Friday, April 19, 2013 8:13 AM


SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Thursday, April 24, 2014 9:12 AM
Points: 285, Visits: 504
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... :)


---------------------------------------------------------------
Mike Hahn - Future MCM 2025
Right way to ask for help!!
http://www.sqlservercentral.com/articles/Best+Practices/61537/
I post so I can see my avatar
I want a personal webpage
I want to win the lotto
I want a gf like Tiffa
Post #1444431
Posted Friday, April 19, 2013 8:21 AM


SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: 2 days ago @ 8:36 AM
Points: 2,612, Visits: 4,709
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/
Post #1444444
Posted Friday, April 19, 2013 9:40 AM


Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, April 23, 2013 5:53 AM
Points: 9, Visits: 35
Thanks, Kingston, I'll give that a try...
Post #1444490
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse