March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hello everyone! I need some help with DAX.
Basically, I have to calculate SELL_THROUGH of the stores (CD_LOJA_SAP) and skus (CD_EAN) where [SELLOUT] AND [POSICAO_ESTOQUE] are not blank ou zero.
Here is an example, using CD_LOJA_SAP:
1. How it is at the moment:
2. How I want it to be:
As you can see, the measure works correctly for the rows in the table. However, the issue lies with the "Total" row. I need it to exclude stores 1 and 2.
My model:
DAX measures:
POSICAO_ESTOQUE_SELLOUT = [SELLOUT] + [POSICAO_ESTOQUE]
Could anyone please help me? Thank you so much!
Solved! Go to Solution.
@Anelyse ,
The issue with the "Total" row in your SELL_THROUGH calculation is due to how Power BI calculates totals in measures. The total is not a sum of the row-level values but rather a recalculation of the measure in the context of all rows.
To fix the issue and exclude stores that should not contribute to the total (e.g., stores 1 and 2 in your example), you need to explicitly filter out those stores where [SELLOUT] or [POSICAO_ESTOQUE] is blank or zero when calculating the total.
Here’s how you can adjust your SELL_THROUGH measure:
SELL_THROUGH =
VAR MaxData = [MAX_DT_ESTOQUE]
VAR Estoque = [POSICAO_ESTOQUE]
VAR Sellout = [SELLOUT]
VAR Estoque_Sellout = [POSICAO_ESTOQUE_SELLOUT]
VAR ST =
SWITCH(
TRUE(),
ISBLANK(Sellout) || ISBLANK(Estoque) || Estoque = 0 || Sellout = 0, BLANK(),
DIVIDE(Sellout, Estoque_Sellout) > 1, 1,
DIVIDE(Sellout, Estoque_Sellout)
)
VAR ValidRows =
SUMX(
FILTER(
ADDCOLUMNS(
VALUES(fEstoque[CD_LOJA_SAP]),
"ValidRow",
NOT(ISBLANK([POSICAO_ESTOQUE])) &&
NOT(ISBLANK([SELLOUT])) &&
[POSICAO_ESTOQUE] > 0 &&
[SELLOUT] > 0
),
[ValidRow]
),
ST
)
RETURN
IF(HASONEVALUE(fEstoque[CD_LOJA_SAP]), ST, ValidRows)
Explanation of the Adjustments:
This approach ensures that the total reflects only the valid rows, excluding stores like 1 and 2 in your example.
Let me know if you need further clarifications or additional adjustments!
Best regards,
@Anelyse ,
The issue with the "Total" row in your SELL_THROUGH calculation is due to how Power BI calculates totals in measures. The total is not a sum of the row-level values but rather a recalculation of the measure in the context of all rows.
To fix the issue and exclude stores that should not contribute to the total (e.g., stores 1 and 2 in your example), you need to explicitly filter out those stores where [SELLOUT] or [POSICAO_ESTOQUE] is blank or zero when calculating the total.
Here’s how you can adjust your SELL_THROUGH measure:
SELL_THROUGH =
VAR MaxData = [MAX_DT_ESTOQUE]
VAR Estoque = [POSICAO_ESTOQUE]
VAR Sellout = [SELLOUT]
VAR Estoque_Sellout = [POSICAO_ESTOQUE_SELLOUT]
VAR ST =
SWITCH(
TRUE(),
ISBLANK(Sellout) || ISBLANK(Estoque) || Estoque = 0 || Sellout = 0, BLANK(),
DIVIDE(Sellout, Estoque_Sellout) > 1, 1,
DIVIDE(Sellout, Estoque_Sellout)
)
VAR ValidRows =
SUMX(
FILTER(
ADDCOLUMNS(
VALUES(fEstoque[CD_LOJA_SAP]),
"ValidRow",
NOT(ISBLANK([POSICAO_ESTOQUE])) &&
NOT(ISBLANK([SELLOUT])) &&
[POSICAO_ESTOQUE] > 0 &&
[SELLOUT] > 0
),
[ValidRow]
),
ST
)
RETURN
IF(HASONEVALUE(fEstoque[CD_LOJA_SAP]), ST, ValidRows)
Explanation of the Adjustments:
This approach ensures that the total reflects only the valid rows, excluding stores like 1 and 2 in your example.
Let me know if you need further clarifications or additional adjustments!
Best regards,
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
User | Count |
---|---|
25 | |
17 | |
16 | |
12 | |
11 |
User | Count |
---|---|
39 | |
29 | |
27 | |
20 | |
18 |