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
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
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.