Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more
Hi everyone! New to the board and excited to learn.
I have two tables, PurchaseAgreement and PurchaseOrderTransactions. What I want is to sum the purchase quantities I have generated under each purchase agreement. The purchase agreements are setup by a Vendor, Item, Warehouse combination and are only valid for a certain period. In my sample data below, I have AgreementID 1 Quantity being a sum of the quantity for PO 1 & 2.
PurchaseAgreement
| AgreementID | StartDate | EndDate | Vendor | Item | Warehouse |
| 1 | 10/1/2022 | 12/31/2022 | Vendor1 | Item1 | Warehouse1 |
| 2 | 8/1/2022 | 9/30/2022 | Vendor1 | Item1 | Warehouse1 |
| 3 | 10/1/2022 | 12/31/2022 | Vendor2 | Item2 | Warehouse2 |
PurchaseOrderTransactions
| PO | DeliveryDate | Vendor | Item | Warehouse | Quantity |
| 1 | 10/1/2022 | Vendor1 | Item1 | Warehouse1 | 100 |
| 2 | 10/2/2022 | Vendor1 | Item1 | Warehouse1 | 200 |
| 3 | 8/1/2022 | Vendor1 | Item1 | Warehouse1 | 400 |
| 4 | 10/1/2022 | Vendor2 | Item2 | Warehouse2 | 500 |
Expected Result:
| AgreementID | StartDate | EndDate | Vendor | Item | Warehouse | Quantity |
| 1 | 10/1/2022 | 12/31/2022 | Vendor1 | Item1 | Warehouse1 | 300 |
| 2 | 8/1/2022 | 9/30/2022 | Vendor1 | Item1 | Warehouse1 | 400 |
| 3 | 10/1/2022 | 12/31/2022 | Vendor2 | Item2 | Warehouse2 | 500 |
I feel like this requires SUMX but I'm open to all ideas.
Solved! Go to Solution.
Hi @hasanhilmi ,
Here I suggest you to create a calculated column by this code.
Quantity =
CALCULATE (
SUM ( PurchaseOrderTransactions[Quantity] ),
FILTER (
PurchaseOrderTransactions,
PurchaseOrderTransactions[Vendor] = EARLIER ( PurchaseAgreement[Vendor] )
&& PurchaseOrderTransactions[Item] = EARLIER ( PurchaseAgreement[Item] )
&& PurchaseOrderTransactions[Warehouse] = EARLIER ( PurchaseAgreement[Warehouse] )
&& AND (
PurchaseOrderTransactions[DeliveryDate]
>= EARLIER ( PurchaseAgreement[StartDate] ),
PurchaseOrderTransactions[DeliveryDate]
<= EARLIER ( PurchaseAgreement[EndDate] )
)
)
)
Result is as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Anonymous thanks for the suggestion!
A few more questions.
This would require a relation between the two tables, correct? What would you suggest as the best way to relate them? Creating a key by concatenating vendor, item and warehouse on both tables? On my real tables this is likely to require a many to many relation and I keep hearing that that's something to be avoided when possible.
Hi @hasanhilmi ,
As far as I know, you don't need to create relationships between two tables. Here we use Table1[Column1] = EARLIER(Table2[Column2]) as condition in our code. So we don't need relationship in data model.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Yup this worked! Great solution!
Hi @hasanhilmi ,
Here I suggest you to create a calculated column by this code.
Quantity =
CALCULATE (
SUM ( PurchaseOrderTransactions[Quantity] ),
FILTER (
PurchaseOrderTransactions,
PurchaseOrderTransactions[Vendor] = EARLIER ( PurchaseAgreement[Vendor] )
&& PurchaseOrderTransactions[Item] = EARLIER ( PurchaseAgreement[Item] )
&& PurchaseOrderTransactions[Warehouse] = EARLIER ( PurchaseAgreement[Warehouse] )
&& AND (
PurchaseOrderTransactions[DeliveryDate]
>= EARLIER ( PurchaseAgreement[StartDate] ),
PurchaseOrderTransactions[DeliveryDate]
<= EARLIER ( PurchaseAgreement[EndDate] )
)
)
)
Result is as below.
Best Regards,
Rico Zhou
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Check out the November 2025 Power BI update to learn about new features.
Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!