I'm trying to roll up spend by child company including all the grandchildren companies without any recursive functions.
My data set looks similar to this format:
Parent A
- Child A.1 - $1,000
- Child A.2 - $2,000
- - Grandchild A.2.1 - $500
- - Grandchild A.2.2 - $750
- Child A.3 - $3,000
- Child A.4 - $4,000
Parent B
- Child B.1 - $11,000
- Child B.2 - $12,000
- - Grandchild B.2.1 - $1,500
- - Grandchild B.2.2 - $1,750
- Child B.3 - $13,000
- Child B.4 - $14,000
What I'd like to do is sum by child for Parent A, so the result would output like:
Child A.1 - $1,000
Child A.2 - $3,250
Child A.3 - $3,000
Child A.4 - $4,000
This is a simplified structure of my companies table:
id
name
parent_id
lft
rght
This is a simplified structure of my spend table:
id
company_id
amount
date
I know how to list out each child and their amounts for just Parent A:
SELECT
`Company`.`name` AS `name`,
SUM(`Spend`.`amount`) AS `amount`
FROM
`spend_table` AS `Spend`
INNER JOIN companies_table AS `Company` ON `Spend`.`company_id` = `Company`.`id`
INNER JOIN companies_table AS `thisCompany` ON `Company`.`lft` BETWEEN `thisCompany`.`lft` AND `thisCompany`.`rght`
WHERE
`thisCompany`.`name` = 'Parent A'
GROUP BY
`Company`.`name`
Which would output:
Child A.1 - $1,000
Child A.2 - $2,000
Grandchild A.2.1 - $500
Grandchild A.2.2 - $750
Child A.3 - $3,000
Child A.4 - $4,000
And I know how to sum for each child (excluding grandchildren) for Parent A:
SELECT
`Company`.`name` AS `name`,
SUM(`Spend`.`amount`) AS `amount`
FROM
`spend_visibility2` AS `SpendVisibility`
`spend_table` AS `Spend`
INNER JOIN companies_table AS `Company` ON `Spend`.`company_id` = `Company`.`id`
INNER JOIN companies_table AS `thisCompany` ON `Company`.`lft` BETWEEN `thisCompany`.`lft` AND `thisCompany`.`rght`
WHERE
`thisCompany`.`name` = 'Parent A'
`Company`.`parent_id` = `thisCompany`.`id`
GROUP BY
`Company`.`name`
Which would output:
Child A.1 - $1,000
Child A.2 - $2,000
Child A.3 - $3,000
Child A.4 - $4,000
Can someone help me? I believe I need a subselect, but am having difficulty figuring it out.
First, select the child companies that you are interested in (table c). I've used a sub-query to easily select the direct children on 'Parent A'. Then join to the companies_table again to retrieve all of the descendants (table alias c2). And finally join to your spend_table to get the amounts which you can aggregate using group by.
select c.name, sum(s.amount)
from companies_table c
join companies_table c2 ON c2.lft between c.lft and c.rght
join spend_table s ON c2.id = s.company_id
where parent_id = (select id from companies_table where name = 'Parent A')
group by c.name