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

Calling all Data Engineers! Fabric Data Engineer (Exam DP-700) live sessions are back! Starting October 16th. Sign up.

Reply
Euro0681
Helper II
Helper II

Conversion into Power BI DAX

I'm having to create a measure that calculates a baseline value (the baseline should be previous fiscal year of the last Quarter (so q4))
I was wondering how this could be achieved, as it was provided to me in a SQL Statement (needed to be created as a measure)

 

SELECT Table.[CC], Sum(IIf([Amount1 USD]=0,[Amount2 USD],[Amount1 USD])) AS [Amount USD], Sum(IIf([Amount1]=0,[Amount2],[Amount1])) AS [Amount]

FROM Table

WHERE (((Table.Period)="202111" Or (Table.Period)="202112" Or (Table.Period)="202201"))

GROUP BY Table.[CC];

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

Hi  @Euro0681 ,

I created some data:

 

vyangliumsft_0-1669084059131.png

Here are the steps you can follow:

1. Create measure.

IF1 =
IF(
   MAX('Table'[Period]) in {"202111","202112","202201"}&&
    MAX('Table'[Amount1 USD])=0,
    MAX('Table'[Amount2 USD]),
    IF(
    MAX('Table'[Period]) in {"202111","202112","202201"},
    MAX('Table'[Amount1 USD]),0))
IF2 =
IF(
    MAX('Table'[Period]) in {"202111","202112","202201"}&&
    MAX('Table'[Amount1])=0,
    MAX('Table'[Amount2]),
    IF(
    MAX('Table'[Period]) in {"202111","202112","202201"},
    MAX('Table'[Amount1]),0))
Sum_Amount =
SUMX(FILTER(ALL('Table'),'Table'[CC]=MAX('Table'[CC])&&'Table'[Period]=MAX('Table'[Period])),[IF2])
Sum_Amount USD =
SUMX(FILTER(ALL('Table'),'Table'[CC]=MAX('Table'[CC])&&'Table'[Period]=MAX('Table'[Period])),[IF1])
Sum_ALL =
var _count=
COUNTX(FILTER(ALL('Table'),'Table'[CC]=MAX('Table'[CC])&&'Table'[Period]=MAX('Table'[Period])),[Period])
var _sumall=
SUMX(FILTER(ALL('Table'),'Table'[CC]=MAX('Table'[CC])&&'Table'[Period]=MAX('Table'[Period])),[Sum_Amount]+[Sum_Amount USD])
return
DIVIDE(
    _sumall,_count)

2. Result:

vyangliumsft_1-1669084059134.png

 

Best Regards,

Liu Yang

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

CNENFRNL_0-1669151272283.png

 

let
    Source = Table.SelectRows(TB, each List.Contains({"202111","202112","202201"},[Period])),
    #"Amount USD" = Table.AddColumn(Source, "Amt USD", each if [Amount1 USD] = 0 then [Amount2 USD] else [Amount1 USD]),
    Amount = Table.AddColumn(#"Amount USD", "Amt", each if [Amount1] = 0 then [Amount2] else [Amount1]),
    Aggregated = Table.Group(Amount, "CC", {"Aggr", each [#"Amount USD"=List.Sum([Amt USD]), Amount=List.Sum([Amt])]}),
    #"Expanded Aggr" = Table.ExpandRecordColumn(Aggregated, "Aggr", {"Amount USD", "Amount"})
in
    #"Expanded Aggr"

CNENFRNL_1-1669151379316.png

 

For fun only, a showcase of powerful Excel worksheet formulas

CNENFRNL_2-1669151480637.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

View solution in original post

2 REPLIES 2
Anonymous
Not applicable

Hi  @Euro0681 ,

I created some data:

 

vyangliumsft_0-1669084059131.png

Here are the steps you can follow:

1. Create measure.

IF1 =
IF(
   MAX('Table'[Period]) in {"202111","202112","202201"}&&
    MAX('Table'[Amount1 USD])=0,
    MAX('Table'[Amount2 USD]),
    IF(
    MAX('Table'[Period]) in {"202111","202112","202201"},
    MAX('Table'[Amount1 USD]),0))
IF2 =
IF(
    MAX('Table'[Period]) in {"202111","202112","202201"}&&
    MAX('Table'[Amount1])=0,
    MAX('Table'[Amount2]),
    IF(
    MAX('Table'[Period]) in {"202111","202112","202201"},
    MAX('Table'[Amount1]),0))
Sum_Amount =
SUMX(FILTER(ALL('Table'),'Table'[CC]=MAX('Table'[CC])&&'Table'[Period]=MAX('Table'[Period])),[IF2])
Sum_Amount USD =
SUMX(FILTER(ALL('Table'),'Table'[CC]=MAX('Table'[CC])&&'Table'[Period]=MAX('Table'[Period])),[IF1])
Sum_ALL =
var _count=
COUNTX(FILTER(ALL('Table'),'Table'[CC]=MAX('Table'[CC])&&'Table'[Period]=MAX('Table'[Period])),[Period])
var _sumall=
SUMX(FILTER(ALL('Table'),'Table'[CC]=MAX('Table'[CC])&&'Table'[Period]=MAX('Table'[Period])),[Sum_Amount]+[Sum_Amount USD])
return
DIVIDE(
    _sumall,_count)

2. Result:

vyangliumsft_1-1669084059134.png

 

Best Regards,

Liu Yang

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

CNENFRNL_0-1669151272283.png

 

let
    Source = Table.SelectRows(TB, each List.Contains({"202111","202112","202201"},[Period])),
    #"Amount USD" = Table.AddColumn(Source, "Amt USD", each if [Amount1 USD] = 0 then [Amount2 USD] else [Amount1 USD]),
    Amount = Table.AddColumn(#"Amount USD", "Amt", each if [Amount1] = 0 then [Amount2] else [Amount1]),
    Aggregated = Table.Group(Amount, "CC", {"Aggr", each [#"Amount USD"=List.Sum([Amt USD]), Amount=List.Sum([Amt])]}),
    #"Expanded Aggr" = Table.ExpandRecordColumn(Aggregated, "Aggr", {"Amount USD", "Amount"})
in
    #"Expanded Aggr"

CNENFRNL_1-1669151379316.png

 

For fun only, a showcase of powerful Excel worksheet formulas

CNENFRNL_2-1669151480637.png


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Helpful resources

Announcements
FabCon Global Hackathon Carousel

FabCon Global Hackathon

Join the Fabric FabCon Global Hackathon—running virtually through Nov 3. Open to all skill levels. $10,000 in prizes!

September Power BI Update Carousel

Power BI Monthly Update - September 2025

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

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.