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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
farhanishango
New Member

Subtracting 2 different columns from 2 different tables

Hi,

 

I am trying to calculate the difference between 2 values from 2 different tables. The data model consists of 3 tables and 5 dimension tables. The 2 tables that have the columns does not have a direct relationship between them. I want the subtraction to take place only when there is a value in the 2 columns. Also, I want to have the total value of this measure.

 

The following screenshot presents the tables and the current measures that I managed to produce (not functioning well!!). I want the card to show 1140. It is showing the same number as the value in the second table which is the sum of the values of 'Value 1' in that table minus the sum of values in the 'Value 2'.

farhanishango_2-1631272215469.png

 

Here is the dax for the measure on the card:

Variance (Value 1 - Value 2)=
VAR __BASELINE_VALUE =
    CALCULATE(
        SUM('F: Forecasted Data'[Value 1]),
        'F: Confirmed Data'[Value 2] <> BLANK(), 'F: Forecasted Data'[Value 1] <> BLANK()
    )
VAR __MEASURE_VALUE = SUM('F: Confirmed Data'[Value 2])
RETURN
    IF(NOT ISBLANK(__MEASURE_VALUE) && NOT ISBLANK(__BASELINE_VALUE), __BASELINE_VALUE - __MEASURE_VALUE )
 
Here is the data model:
farhanishango_3-1631272472644.png

 

 
Thanks
1 ACCEPTED SOLUTION

Hi, @farhanishango 

Hope the following formula could work.

Variance (Value 1 - Value 2) =
VAR tab =
    CROSSJOIN ( 'D:Location', 'D:Date' )
VAR tab2 =
    FILTER (
        ADDCOLUMNS (
            tab,
            "v1",
                CALCULATE (
                    SUM ( 'F: Forecasted Data'[Value 1] ),
                    FILTER (
                        tab,
                        [Date] = EARLIER ( 'D:Date'[Date] )
                            && [sheetName] = EARLIER ( 'D:Location'[sheetName] )
                    )
                ),
            "v2",
                CALCULATE (
                    SUM ( 'F: Confirmed Data'[Value 2] ),
                    FILTER (
                        tab,
                        [Date] = EARLIER ( 'D:Date'[Date] )
                            && [sheetName] = EARLIER ( 'D:Location'[sheetName] )
                    )
                )
        ),
        [v1] <> BLANK ()
            && [v2] <> BLANK ()
    )
RETURN
    SUMX ( tab2, [v1] - [v2] )

Best Regards,
Community Support Team _ Eason

View solution in original post

3 REPLIES 3
amitchandak
Super User
Super User

@farhanishango , Try return like

 

 

return
sumx(summarize('F: Forecasted Data', 'D: Location' [location], Date[Date], "_1", IF(NOT ISBLANK(__MEASURE_VALUE) && NOT ISBLANK(__BASELINE_VALUE), __BASELINE_VALUE - __MEASURE_VALUE )), [_1])

Hi @amitchandak,

Here is what I got:

farhanishango_0-1631273592419.png

 

Hi, @farhanishango 

Hope the following formula could work.

Variance (Value 1 - Value 2) =
VAR tab =
    CROSSJOIN ( 'D:Location', 'D:Date' )
VAR tab2 =
    FILTER (
        ADDCOLUMNS (
            tab,
            "v1",
                CALCULATE (
                    SUM ( 'F: Forecasted Data'[Value 1] ),
                    FILTER (
                        tab,
                        [Date] = EARLIER ( 'D:Date'[Date] )
                            && [sheetName] = EARLIER ( 'D:Location'[sheetName] )
                    )
                ),
            "v2",
                CALCULATE (
                    SUM ( 'F: Confirmed Data'[Value 2] ),
                    FILTER (
                        tab,
                        [Date] = EARLIER ( 'D:Date'[Date] )
                            && [sheetName] = EARLIER ( 'D:Location'[sheetName] )
                    )
                )
        ),
        [v1] <> BLANK ()
            && [v2] <> BLANK ()
    )
RETURN
    SUMX ( tab2, [v1] - [v2] )

Best Regards,
Community Support Team _ Eason

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

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