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
Anonymous
Not applicable

Help with measure: SUM and IF

Hello guys, I'm trying to convert from positive to negative in a measure when a certain filter is applied:

 

Fact. Acumulado = 
CALCULATE(
    CALCULATE(         
        IF(
            FIRSTNONBLANK('Table'[AGENCIA_ORIGINAL];1)=FIRSTNONBLANK(Dim_agencia[Agencia];1);
            SUM('Table'[FACTURACION])*-1;
            SUM('Table'[FACTURACION])
        );
        FILTER(
            'Table';
            'Table'[AGENCIA_ORIGINAL]=FIRSTNONBLANK(Dim_agencia[Agencia];1) || 'Table'[AGENCIA_MODIFICADA]=FIRSTNONBLANK(Dim_agencia[Agencia];1))
    );
SAMEPERIODLASTYEAR(DATESYTD(Calendario[Date]))
)

 


The thing is the measure is working partiallty because inside the table it shows the correct results but it doesn't for the grand total:

sample.PNG

I'm not sure why, but it might be because for the grand total is applying the "ELSE" condition from the IF Function?

SUM('Table'[FACTURACION])*-1

I've tryied to do it with SUMX without any luck, maybe I'm not doing it right or it is not the answer.
Let me know if it's not clear what I'm trying to do, because I know it's strange and my english doesn't help neither.
Thank you!!
1 ACCEPTED SOLUTION

Hi, @Anonymous 

 

You may modify the measures as below.

Fact. Acumulado = 
SUMX(
    DISTINCT('Table'[ANUNCIANTE]),
    CALCULATE(
        CALCULATE(         
            IF(
                FIRSTNONBLANK('Table'[AGENCIA_ORIGINAL],1)=FIRSTNONBLANK(Dim_agencia[Agencia],1),
                SUM('Table'[FACTURACION])*-1,
                SUM('Table'[FACTURACION])
            ),
            FILTER(
                'Table',
                'Table'[AGENCIA_ORIGINAL]=FIRSTNONBLANK(Dim_agencia[Agencia],1) || 'Table'[AGENCIA_MODIFICADA]=FIRSTNONBLANK(Dim_agencia[Agencia],1))
        ),
        SAMEPERIODLASTYEAR(DATESYTD(Calendario[Date]))
    )
)

Fact. año completo = 
SUMX(
    DISTINCT('Table'[ANUNCIANTE]),
    CALCULATE(
        CALCULATE(         
            IF(
                FIRSTNONBLANK('Table'[AGENCIA_ORIGINAL],1)=FIRSTNONBLANK(Dim_agencia[Agencia],1),
                SUM('Table'[FACTURACION])*-1,
                SUM('Table'[FACTURACION])
            ),
            FILTER(
                'Table',
                'Table'[AGENCIA_ORIGINAL]=FIRSTNONBLANK(Dim_agencia[Agencia],1) || 'Table'[AGENCIA_MODIFICADA]=FIRSTNONBLANK(Dim_agencia[Agencia],1)
            )
        ),
        PARALLELPERIOD(Calendario[Date],-1,YEAR)
    )
)

 

Result:

c1.png

 

Best Regards

Allan

 

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

3 REPLIES 3
amitchandak
Super User
Super User

@Anonymous , like

Fact. Acumulado =
CALCULATE(
CALCULATE(
IF(
FIRSTNONBLANK('Table'[AGENCIA_ORIGINAL];1)=FIRSTNONBLANK(Dim_agencia[Agencia];1);
SUM('Table'[FACTURACION])*-1;
SUM('Table'[FACTURACION])
);
FILTER(
'Table';
'Table'[AGENCIA_ORIGINAL]=FIRSTNONBLANK(Dim_agencia[Agencia];1) || 'Table'[AGENCIA_MODIFICADA]=FIRSTNONBLANK(Dim_agencia[Agencia];1))
);
SAMEPERIODLASTYEAR(DATESYTD(Calendario[Date]))
;values('Table'[ANUCIANTE])
)
or an ew measaure on top of last one
new Fact. Acumulado =
sumx(summarize( 'Table', 'Table'[ANUCIANTE],"_1",[Fact. Acumulado]),[_1])

Anonymous
Not applicable

Hi @amitchandak 

 

Neither of the results is working. The first one just gives me the same result I was getting before, the other one is blank. But I get it's hard to make it work without any data.

Since the data inside it's just for testing I uploaded the PBIX in case anyone want to test if can make that work.

Download the pbix 

Thank you!

Hi, @Anonymous 

 

You may modify the measures as below.

Fact. Acumulado = 
SUMX(
    DISTINCT('Table'[ANUNCIANTE]),
    CALCULATE(
        CALCULATE(         
            IF(
                FIRSTNONBLANK('Table'[AGENCIA_ORIGINAL],1)=FIRSTNONBLANK(Dim_agencia[Agencia],1),
                SUM('Table'[FACTURACION])*-1,
                SUM('Table'[FACTURACION])
            ),
            FILTER(
                'Table',
                'Table'[AGENCIA_ORIGINAL]=FIRSTNONBLANK(Dim_agencia[Agencia],1) || 'Table'[AGENCIA_MODIFICADA]=FIRSTNONBLANK(Dim_agencia[Agencia],1))
        ),
        SAMEPERIODLASTYEAR(DATESYTD(Calendario[Date]))
    )
)

Fact. año completo = 
SUMX(
    DISTINCT('Table'[ANUNCIANTE]),
    CALCULATE(
        CALCULATE(         
            IF(
                FIRSTNONBLANK('Table'[AGENCIA_ORIGINAL],1)=FIRSTNONBLANK(Dim_agencia[Agencia],1),
                SUM('Table'[FACTURACION])*-1,
                SUM('Table'[FACTURACION])
            ),
            FILTER(
                'Table',
                'Table'[AGENCIA_ORIGINAL]=FIRSTNONBLANK(Dim_agencia[Agencia],1) || 'Table'[AGENCIA_MODIFICADA]=FIRSTNONBLANK(Dim_agencia[Agencia],1)
            )
        ),
        PARALLELPERIOD(Calendario[Date],-1,YEAR)
    )
)

 

Result:

c1.png

 

Best Regards

Allan

 

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

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.