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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
clock0928
Helper I
Helper I

Creating Excel formula in Power Bi

Hi all,
I understand that this is probably a specific issue to myself, however if you have time to assist that would be greatly appreciated!
Currently I have a 4 tables in my Power Bi:

  1. Calendar
    • Date
    • WeekOfYear
  2. Team Members
    • Full Name
  3. Daily Statistics
    • Date (linked to Calendar table)
    • Full Name (linked to Team Members table)
    • CarsCounted
    • ToolsCounted
  4. Work On Hand
    • Date (linked to Calendar table)
    • Full Name (linked to Team Members table)
    • CarsOnHand
    • ToolsOnHand

From this, I want to replicate a formula from Excel that looks something like this - 
"Current Weeks CarsOnHand" - "Previous Weeks CarsOnHand" + "Previous Weeks CarsCounted" (screenshot attached)

What would be my best way to approach this in Power Bi? I feel like I have all the right information for it to be achieved, just having some troubles with executing it.
Any help is appreciated.

 

PowerBiSample.png

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @clock0928 ,

I will start by showing you my test data:

vjunyantmsft_0-1700624995332.pngvjunyantmsft_1-1700625004387.pngvjunyantmsft_2-1700625013299.pngvjunyantmsft_3-1700625021154.png

To make it easier to see, I created a week table and used that to create a slicer:

vjunyantmsft_4-1700625103467.pngvjunyantmsft_5-1700625111460.png

I then used DAX to create the following three measures:

Total_CarsOnHand = 
CALCULATE(
    SUM('Work On Hand'[CarsOnHand]),
    FILTER(
        ALLSELECTED('Calendar'[WeekOfYear]),
        'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo])
    )
)
LastWeek_Total_CarsOnHand = 
CALCULATE(
    SUM('Work On Hand'[CarsOnHand]),
        'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo]) - 1, ALL('Calendar')
    )
LastWeek_Total_CarsCounted = 
CALCULATE(
    SUM('Daily Statistics'[CarsCounted]),
        'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo]) - 1, ALL('Calendar')
    )

The three measures can then be used to perform the calculation steps you require:

Measure = 'Work On Hand'[Total_CarsOnHand] - 'Work On Hand'[LastWeek_Total_CarsOnHand] + 'Daily Statistics'[LastWeek_Total_CarsCounted]

The final result is shown below:

vjunyantmsft_6-1700625360556.png

 

Best Regards,

Dino Tao

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

4 REPLIES 4
clock0928
Helper I
Helper I

This is fantastic, thank you @Anonymous !
Is there a way to have the filter based on my calendar table if I already have a field of "WeekOfYear"?

Anonymous
Not applicable

Hi @clock0928,

Of course you can, just change the 

SELECTEDVALUE('Slicer'[WeekNo])

into

SELECTEDVALUE('Calendar'[WeekOfYear])

in the three DAXs, and I've tested them and they still work fine in my sample data.

Best Regards,
Dino Tao

@Anonymous love your work - thank you again for the assistance 🙂

Anonymous
Not applicable

Hi @clock0928 ,

I will start by showing you my test data:

vjunyantmsft_0-1700624995332.pngvjunyantmsft_1-1700625004387.pngvjunyantmsft_2-1700625013299.pngvjunyantmsft_3-1700625021154.png

To make it easier to see, I created a week table and used that to create a slicer:

vjunyantmsft_4-1700625103467.pngvjunyantmsft_5-1700625111460.png

I then used DAX to create the following three measures:

Total_CarsOnHand = 
CALCULATE(
    SUM('Work On Hand'[CarsOnHand]),
    FILTER(
        ALLSELECTED('Calendar'[WeekOfYear]),
        'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo])
    )
)
LastWeek_Total_CarsOnHand = 
CALCULATE(
    SUM('Work On Hand'[CarsOnHand]),
        'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo]) - 1, ALL('Calendar')
    )
LastWeek_Total_CarsCounted = 
CALCULATE(
    SUM('Daily Statistics'[CarsCounted]),
        'Calendar'[WeekOfYear] = SELECTEDVALUE('Slicer'[WeekNo]) - 1, ALL('Calendar')
    )

The three measures can then be used to perform the calculation steps you require:

Measure = 'Work On Hand'[Total_CarsOnHand] - 'Work On Hand'[LastWeek_Total_CarsOnHand] + 'Daily Statistics'[LastWeek_Total_CarsCounted]

The final result is shown below:

vjunyantmsft_6-1700625360556.png

 

Best Regards,

Dino Tao

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

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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