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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
mwild
Frequent Visitor

Calculated Table

Hi,

I have a table in Excel (to be imported into Power Bi) which has dates down one side (running from January 2010 to way into the future)
My columns are vehicles A, B and C (but over 100 of them) and the date within the spreadsheet is cumulative miles

mwild_0-1641398235262.png


I'm looking at creating a new table which will show me the daily miles instead so A would show 232 which is the difference between 15th and 16th

Does anyone know of a way to do this please?



2 ACCEPTED SOLUTIONS
PaulDBrown
Community Champion
Community Champion

Firstly I would recommend you Unpivot the Vehicle columns. 

Unpivot.jpg

 

You can then create a calculated column to get the daily mileage for each vehicle using:

 

Daily Mileage =
VAR PrevDate =
    CALCULATE (
        SUM ( 'DataTable'[Mileage] ),
        FILTER (
            'DataTable',
            'DataTable'[Vehicle] = EARLIER ( 'DataTable'[Vehicle] )
                && 'DataTable'[Date]
                    = EARLIER ( 'DataTable'[Date] ) - 1
        )
    )
VAR CurrDate =
    CALCULATE (
        SUM ( 'DataTable'[Mileage] ),
        FILTER (
            'DataTable',
            'DataTable'[Vehicle] = EARLIER ( 'DataTable'[Vehicle] )
                && 'DataTable'[Date] = EARLIER ( 'DataTable'[Date] )
        )
    )
RETURN
    CurrDate - PrevDate

 

 

To get:

Daily Mielage.jpg

If you want the "Daily Mileage" for the first (minimum) date to be blank, use:

Daily Mileage =
VAR MinDate =
    MIN ( 'DataTable'[Date] )
VAR PrevDate =
    CALCULATE (
        SUM ( 'DataTable'[Mileage] ),
        FILTER (
            'DataTable',
            'DataTable'[Vehicle] = EARLIER ( 'DataTable'[Vehicle] )
                && 'DataTable'[Date]
                    = EARLIER ( 'DataTable'[Date] ) - 1
        )
    )
VAR CurrDate =
    CALCULATE (
        SUM ( 'DataTable'[Mileage] ),
        FILTER (
            'DataTable',
            'DataTable'[Vehicle] = EARLIER ( 'DataTable'[Vehicle] )
                && 'DataTable'[Date] = EARLIER ( 'DataTable'[Date] )
        )
    )
RETURN
    IF ( 'DataTable'[Date] = MinDate, BLANK (), CurrDate - PrevDate )

I've attached the sample PBIX file





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






View solution in original post

does exactly as I needed - thanks for this 👍

 

View solution in original post

3 REPLIES 3
PaulDBrown
Community Champion
Community Champion

Firstly I would recommend you Unpivot the Vehicle columns. 

Unpivot.jpg

 

You can then create a calculated column to get the daily mileage for each vehicle using:

 

Daily Mileage =
VAR PrevDate =
    CALCULATE (
        SUM ( 'DataTable'[Mileage] ),
        FILTER (
            'DataTable',
            'DataTable'[Vehicle] = EARLIER ( 'DataTable'[Vehicle] )
                && 'DataTable'[Date]
                    = EARLIER ( 'DataTable'[Date] ) - 1
        )
    )
VAR CurrDate =
    CALCULATE (
        SUM ( 'DataTable'[Mileage] ),
        FILTER (
            'DataTable',
            'DataTable'[Vehicle] = EARLIER ( 'DataTable'[Vehicle] )
                && 'DataTable'[Date] = EARLIER ( 'DataTable'[Date] )
        )
    )
RETURN
    CurrDate - PrevDate

 

 

To get:

Daily Mielage.jpg

If you want the "Daily Mileage" for the first (minimum) date to be blank, use:

Daily Mileage =
VAR MinDate =
    MIN ( 'DataTable'[Date] )
VAR PrevDate =
    CALCULATE (
        SUM ( 'DataTable'[Mileage] ),
        FILTER (
            'DataTable',
            'DataTable'[Vehicle] = EARLIER ( 'DataTable'[Vehicle] )
                && 'DataTable'[Date]
                    = EARLIER ( 'DataTable'[Date] ) - 1
        )
    )
VAR CurrDate =
    CALCULATE (
        SUM ( 'DataTable'[Mileage] ),
        FILTER (
            'DataTable',
            'DataTable'[Vehicle] = EARLIER ( 'DataTable'[Vehicle] )
                && 'DataTable'[Date] = EARLIER ( 'DataTable'[Date] )
        )
    )
RETURN
    IF ( 'DataTable'[Date] = MinDate, BLANK (), CurrDate - PrevDate )

I've attached the sample PBIX file





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






does exactly as I needed - thanks for this 👍

 

mh2587
Super User
Super User

please provide sample data and expected result for the issue


Did I answer your question? If so, please mark my post as a solution!


Proud to be a Super User!




LinkedIn Icon
Muhammad Hasnain



Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 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.