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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
hoa3nok7
Frequent Visitor

Switching Signs in Power BI

Hi everyone,

 

My data is like this. Each group has corresponding amount and I only flip the amount for group A and B, but keep the sign for C and D the same.

 

FYPeriodGroupingAmountFlipped Amount
20211A9-9
20211B3-3
20211C2020
20211D1515
20201A4-4
20201B16-16
20201C-21-21
20201D1313
20191A15-15
20192B14-14

 

Below is the Matrix I want to achieve - the total should be equal to -A+(-B)-C-D; this is the reason why I used the flipped amount column to generate the CFY YTD and PFY YTD measures.

 

Grouping CFY YTDPFY YTD
A3 (Flipped)2 (Flipped)
B-5 (Flipped)-4 (Flipped)
C7 (Not flipped)6 (Not flipped)
D9 (Not Flipped)8 (Not Flipped)
Total -18-16

 

However, the current matrix I have is like below

Grouping CFY YTD PFY YTD 
A32
B-5-4
C-7-6
D-9-8
Total -18-16

 

The dax formula I am using is in below. Can anyone please pinpoint a direction?

 

CFY YTD:=
CALCULATE (
SUM ( 'Table1'[Flipped Amount]),
FILTER (
'Table1',
'Table1'[FISCAL_YEAR] = [Selected Fiscal Year]
),
FILTER (
'Table1',
'Table1'[PERIOD] <= [Selected Period]
),
FILTER (
'Table1',
'Table1'[Grouping] = "A"
|| 'Table1'[Grouping] = "B"
)
)
-CALCULATE (
SUM ( 'Table1'[Flipped Amount]),
FILTER (
'Table1',
'Table1'[FISCAL_YEAR] = [Selected Fiscal Year]
),
FILTER (
'Table1',
'Table1'[PERIOD] <= [Selected Period]
),
FILTER (
'Table1',
'Table1'[Grouping] = "C"
|| 'Table1'[Grouping] = "D"
)
)

2 ACCEPTED SOLUTIONS
jennratten
Super User
Super User

Hello - I recommend you add a mapping table that indicates the desired flip behavior and then relate it to the fact table and incorporate it into your calculation.  

 

GroupingFlip Behavior
A-1
B-1
C1
D1

View solution in original post

v-angzheng-msft
Community Support
Community Support

Hi, @hoa3nok7 

In this case, I think the flipped amount column is not necessary.
You can use the ISINSCOP function to calculate the total separately.

vangzhengmsft_0-1639124729924.png

Modify the above measures as follows:

 

Measure =
VAR _SUM_AB =
    CALCULATE (
        SUM ( 'Table1'[Amount] ),
        FILTER ( 'Table1', 'Table1'[FISCAL_YEAR] = [Selected Fiscal Year] ),
        FILTER ( 'Table1', 'Table1'[PERIOD] <= [Selected Period] ),
        FILTER ( 'Table1', 'Table1'[Grouping] = "A" || 'Table1'[Grouping] = "B" )
    )
VAR _SUM_CD =
    CALCULATE (
        SUM ( 'Table1'[Amount] ),
        FILTER ( 'Table1', 'Table1'[FISCAL_YEAR] = [Selected Fiscal Year] ),
        FILTER ( 'Table1', 'Table1'[PERIOD] <= [Selected Period] ),
        FILTER ( 'Table1', 'Table1'[Grouping] = "C" || 'Table1'[Grouping] = "D" )
    )
VAR _SUM_ALL =
    CALCULATE (
        SUM ( 'Table1'[Amount] ),
        FILTER ( 'Table1', 'Table1'[FISCAL_YEAR] = [Selected Fiscal Year] ),
        FILTER ( 'Table1', 'Table1'[PERIOD] <= [Selected Period] )
    )
RETURN
    IF (
        ISINSCOPE ( 'Table'[Grouping] ),
        // 1,
        - ( _SUM_AB ) + _SUM_CD,
        // 2
        - ( _SUM_ALL )
    )

 

If this doesn't work, could you please consdier sharing more details about it and posting expected result so it is clear on what needs to be implemented?  And It would be great if there is a sample file without any sesentive information here. It makes it easier to give you a solution.

 

 

Best Regards,
Community Support Team _ Zeon Zheng


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

5 REPLIES 5
v-angzheng-msft
Community Support
Community Support

Hi, @hoa3nok7 

In this case, I think the flipped amount column is not necessary.
You can use the ISINSCOP function to calculate the total separately.

vangzhengmsft_0-1639124729924.png

Modify the above measures as follows:

 

Measure =
VAR _SUM_AB =
    CALCULATE (
        SUM ( 'Table1'[Amount] ),
        FILTER ( 'Table1', 'Table1'[FISCAL_YEAR] = [Selected Fiscal Year] ),
        FILTER ( 'Table1', 'Table1'[PERIOD] <= [Selected Period] ),
        FILTER ( 'Table1', 'Table1'[Grouping] = "A" || 'Table1'[Grouping] = "B" )
    )
VAR _SUM_CD =
    CALCULATE (
        SUM ( 'Table1'[Amount] ),
        FILTER ( 'Table1', 'Table1'[FISCAL_YEAR] = [Selected Fiscal Year] ),
        FILTER ( 'Table1', 'Table1'[PERIOD] <= [Selected Period] ),
        FILTER ( 'Table1', 'Table1'[Grouping] = "C" || 'Table1'[Grouping] = "D" )
    )
VAR _SUM_ALL =
    CALCULATE (
        SUM ( 'Table1'[Amount] ),
        FILTER ( 'Table1', 'Table1'[FISCAL_YEAR] = [Selected Fiscal Year] ),
        FILTER ( 'Table1', 'Table1'[PERIOD] <= [Selected Period] )
    )
RETURN
    IF (
        ISINSCOPE ( 'Table'[Grouping] ),
        // 1,
        - ( _SUM_AB ) + _SUM_CD,
        // 2
        - ( _SUM_ALL )
    )

 

If this doesn't work, could you please consdier sharing more details about it and posting expected result so it is clear on what needs to be implemented?  And It would be great if there is a sample file without any sesentive information here. It makes it easier to give you a solution.

 

 

Best Regards,
Community Support Team _ Zeon Zheng


If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

@v-angzheng-msft 

 

Thank you Zeon for your response. It looks like the ISINSCOPE does not work when connection type is LIVE (SSAS tabular). Do you know any equivalent way that I can avoid it? Thank you.

screenshot to pbi community.PNG

Hi, @hoa3nok7 

 

How about using these two functions?

HASONEVALUE

ISFILTERED

RETURN IF (HASONEVALUE ( 'Table'[Grouping] ),1,2)
RETURN IF (ISFILTERED( 'Table'[Grouping] ),1,2)

 

I seem to be able to use this function in SSAS. Am i missing something?

vangzhengmsft_0-1639382790993.png

 

 

Best Regards,
Community Support Team _ Zeon Zheng


If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

AlexisOlson
Super User
Super User

I can't tell how you are getting the values in the matrix you want to achieve from the data you provided.

jennratten
Super User
Super User

Hello - I recommend you add a mapping table that indicates the desired flip behavior and then relate it to the fact table and incorporate it into your calculation.  

 

GroupingFlip Behavior
A-1
B-1
C1
D1

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors
Top Kudoed Authors