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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
BI2018No
Frequent Visitor

SumProduct in measure

Hello technical experts!

 

I would like to perform a "sumproduct" on two time series in the same datatable. All ID1 should be multiplied by ID2 for all time slots. How can I do this using DAX formulas in a measure? 

 

TimeIDValue
01.01.2018112
02.01.2018114
03.01.2018116
01.01.20182100
02.01.20182200
03.01.20182300

 

 12*100
+14*200
+16*300
=8800
1 ACCEPTED SOLUTION
OwenAuger
Super User
Super User

Hi there,

 

With your existing table, a measure like this using SUMX will give you the result you're looking for. I've used variables to make the calculation clearer.

SumProduct measure = 
SUMX (
    VALUES ( YourTable[Time] ),
    VAR ValueID1 =
        CALCULATE ( SUM ( YourTable[Value] ), YourTable[ID] = 1 )
    VAR ValueID2 =
        CALCULATE ( SUM ( YourTable[Value] ), YourTable[ID] = 2 )
    RETURN
        ValueID1 * ValueID2
)

Regards

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
LinkedIn

View solution in original post

6 REPLIES 6
Edmundas
Frequent Visitor

Hi, could you please help me write sumproduct in DAX as it is shown in example (column "Result')? Thanks a lot

 

Sumproduct.jpg

@Edmundas 

You could also create this column further upstream (e.g. Power Query).

 

However, below is an example of how to calculate with DAX (PBIX attached).

 

Since your Excel formula uses a combination of SUMPRODUCTs to calculate a conditional sum, you can replicate the behaviour with a calculated column like this:

Result = 
CALCULATE (
    SUM ( Data[Ratio] ),
    ALLEXCEPT ( Data, Data[Date], Data[Region] )
)

 


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
LinkedIn
OwenAuger
Super User
Super User

Hi there,

 

With your existing table, a measure like this using SUMX will give you the result you're looking for. I've used variables to make the calculation clearer.

SumProduct measure = 
SUMX (
    VALUES ( YourTable[Time] ),
    VAR ValueID1 =
        CALCULATE ( SUM ( YourTable[Value] ), YourTable[ID] = 1 )
    VAR ValueID2 =
        CALCULATE ( SUM ( YourTable[Value] ), YourTable[ID] = 2 )
    RETURN
        ValueID1 * ValueID2
)

Regards

Owen


Owen Auger
Did I answer your question? Mark my post as a solution!
Blog
LinkedIn

Thanks a lot for a quick and great answer!

 

One more question if I can allow myself.

 

If ValueID1 represents and hourly price, and ValueID2 represents products sold, and I want to return an weighted avrerage price, then I'll have to devide the answer here with the SUMX of ValueID2 i guess? How can this be done in a good way?

 

SumProduct measure = 
SUMX (
    VALUES ( YourTable[Time] ),
    VAR ValueID1 =
        CALCULATE ( SUM ( YourTable[Value] ), YourTable[ID] = 1 )
    VAR ValueID2 =
        CALCULATE ( SUM ( YourTable[Value] ), YourTable[ID] = 2 )
    RETURN
        ValueID1 * ValueID2
)

 

Hi @BI2018No

 

Just another way of doing it. ....

 

MEasure =
SUMX ( VALUES ( Table1[Time] ), CALCULATE ( PRODUCT ( Table1[Value] ) ) )

Helpful resources

Announcements
July 2025 community update carousel

Fabric Community Update - July 2025

Find out what's new and trending in the Fabric community.

July PBI25 Carousel

Power BI Monthly Update - July 2025

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