Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
hasanhilmi
Frequent Visitor

Calculating Purchase Quantities under Purchase Agreement

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

AgreementIDStartDateEndDateVendorItemWarehouse
110/1/202212/31/2022Vendor1Item1Warehouse1
28/1/20229/30/2022Vendor1Item1Warehouse1
310/1/202212/31/2022Vendor2Item2Warehouse2

 

PurchaseOrderTransactions

PODeliveryDateVendorItemWarehouseQuantity
110/1/2022Vendor1Item1Warehouse1100
210/2/2022Vendor1Item1Warehouse1200
38/1/2022Vendor1Item1Warehouse1400
410/1/2022Vendor2Item2Warehouse2500

 

Expected Result:

AgreementIDStartDateEndDateVendorItemWarehouseQuantity
110/1/202212/31/2022Vendor1Item1Warehouse1300
28/1/20229/30/2022Vendor1Item1Warehouse1400
310/1/202212/31/2022Vendor2Item2Warehouse2500

 

I feel like this requires SUMX but I'm open to all ideas. 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

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.

RicoZhou_0-1666159815238.png

 

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.

View solution in original post

4 REPLIES 4
hasanhilmi
Frequent Visitor

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. 

Anonymous
Not applicable

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!

Anonymous
Not applicable

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.

RicoZhou_0-1666159815238.png

 

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.

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 2025 Power BI update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors
Top Kudoed Authors