Suppose for account X you have one allocation for $1000 and two obligations for $100 and $200. When you join the tables, you get two records like this
Code:
X $1000 $100 [net $900]
X $1000 $200 [net $800]
X $2000 $300 [net $1700] GROUP LEVEL
Suppose for account Y you have two allocations for $1000 and $1500 and three obligations for $100, $150 and $200. When you join the tables, you get six records like this
Code:
X $1000 $100 [net $900]
X $1000 $150 [net $850]
X $1000 $200 [ne t $800]
X $1500 $100 [net $1400]
X $1500 $150 [net $1350]
X $1500 $200 [net $1300]
X $7500 $900 [net $6600] GROUP LEVEL
What you have is a partial CROSS JOIN. You can't join them that way and get sensible results. You'll need a UNION. Something like the following:
Code:
SELECT Account, Sum(NetAllocation) AS NetAllocation
FROM
(
SELECT TA.Account AS Account, TA.AllocationAmount AS NetAllocation
FROM tblALLOCATIONS As TA
UNION
SELECT TO.Account AS Account, TO.ObligationAmount AS NetAllocation
FROM tblOBLIGATIONS As TO
)
GROUP BY ACCOUNT
Or if UNIONs make you queasy, you can do the SUMs of each table, then LEFT JOIN them after the GROUP BY has combined the allocations and the obligations to a single record each:
Code:
SELECT Account, (SumAllocation - NZ(SumObligation,0)) AS NetAllocation
FROM
(
SELECT TA.Account, Sum(TA.AllocationAmount) AS SumAllocation
FROM tblALLOCATIONS As TA
GROUP BY TA.Account
)
LEFT JOIN
(
SELECT TO.Account, Sum(TO.ObligationAmount) AS SumObligation
FROM tblOBLIGATIONS As TO
GROUP BY TO.Account
)
ON TA.Account = TO.Account
The above assumes there will always be an allocation before there is an obligation. I did a LEFT JOIN to avoid killing allocations that hadn't been obligated yet. If there may be obligations beofrer the allocation gets entered, then you might want to do a full outer join and add a the NZ function around the SumAllocation term.