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
Anonymous
Not applicable

Maximum Mileage

Hi - hope you can help

I have two tables.

 

A fact table - Table 1

 

Table1.PNG

A dim table - Table 2

 

Table2.PNG


They are joined together using the Post Code Column.

I'm wanting to create a measure that will display as a new column in a table visual of the fact table. I want it to look like the below:

 

Table3.PNG


This column (measure) shows the maximum (highest) mileage for any given Booking Number based on the Post Codes associated with that booking. As an example booking number 689053 has three post codes associated with it - the one with the highest miles is SE at 70 miles - so in the maximum miles column it says 70 for all of the 689053 booking numbers.

Please could you help me with a measure as I'm stumped.

I hope this makes sense.

Kind regards

Chris

1 ACCEPTED SOLUTION

see a link to pbix file with example. it shows two solutions:

1) calculated column (witn no summarized values option chosen)

2) a measure solution (just drop it to matrix and it should work)

 

https://1drv.ms/u/s!AhUWZ84uo7UAgluNh-SF2xKZltBK

View solution in original post

10 REPLIES 10
bogomda
Helper II
Helper II

Chris,

do following:

1. create new calculated column "Maximum Miles" in table1

2. paste following formula and you will get desired results

 

In your case it make sense to create a calculated column (not a measure) because you need to update your column upon addition of new records.

 

=
VAR CurrentBooking = Table1[Booking Number]
RETURN
MAXX(
	FILTER(Table1,Table1[Booking Number]=CurrentBooking),
	RELATED(Table2[Miles])
	)
		

 

this is the link to a sample solution - https://1drv.ms/x/s!AhUWZ84uo7UAglc8kvkwm1THdmsj 

Anonymous
Not applicable

Hi Zubair_Muhammad & bogomda

 

Thank you both for your quick and detailed responses.

 

@Zubair_Muhammad   - Thanks for your efforts but unfortunately I couldn’t get them to give the desired result.

 

@bogomda  - This works really well.

 

BUT!! – apologies – when I simplified the test data I over simplified and missed out a key element.

 

Blow is a screen shot from the pbix file.  I think you’ll instantly see my problem. 

 

Drop Number pic.JPG

 

There is a column called ‘Drop Number’ – each Booking Number and Postcode can have multiple lines in the Fact table as there are potentially multiple drop numbers.

 

Although in this instance I’m not interested in this column it is causing an issue when it feeds through into the ‘desired result’ as it’s summing up the ‘MaxMiles’ row by row.

 

 

ActualandDesired pic.JPG

 

Really sorry I missed this out.  Hopefully it’s just a tweak of the existing formula?

 

Thanks again both – much appreciated.

 

Chris

 

 

 

 

Visual by defaul sums numerical values. You need to left click on Maximum Miles value under Values section and choose option "Don't Summarize" to get desired result

Capture.PNG

see a link to pbix file with example. it shows two solutions:

1) calculated column (witn no summarized values option chosen)

2) a measure solution (just drop it to matrix and it should work)

 

https://1drv.ms/u/s!AhUWZ84uo7UAgluNh-SF2xKZltBK

Anonymous
Not applicable

Thanks very much, that works perfectly 😄

 

Chris

Zubair_Muhammad
Community Champion
Community Champion

@Anonymous 

 

Try this mEasure

 

Measure =
CALCULATE (
    MAX ( Dim[Miles] ),
    CROSSFILTER ( Dim[Post Code], 'Fact'[Post Code], BOTH ),
    CALCULATETABLE (
        VALUES ( 'Fact'[Post Code] ),
        ALLEXCEPT ( 'Fact', 'Fact'[Booking Number] )
    )
)

Regards
Zubair

Please try my custom visuals
Anonymous
Not applicable

Hi Zubair

 

Many thanks for your speedy response.  I have tried the measure and have got the below result:

 

Capture.PNG

 

However this is not quite what I was after.  Please could you have another look?

 

Thank you

 

Chris

 

HI @Anonymous 

 

Please try this MEASURE

Could you share your file

 

Measure = VAR myvalues= CALCULATETABLE (
        VALUES ( 'Fact'[Post Code] ),
        ALLEXCEPT ( 'Fact', 'Fact'[Booking Number] )
    )
RETURN
CALCULATE (
    MAX ( Dim[Miles] ),
    Filter(all(Dim),Dim[Post Code] in myvalues))

Regards
Zubair

Please try my custom visuals

@Anonymous

 

or this one

 

Measure=CALCULATE (
    MAX ( Dim[Miles] ),
TREATAS(CALCULATETABLE (
        VALUES ( 'Fact'[Post Code] ),
        ALLEXCEPT ( 'Fact', 'Fact'[Booking Number] )
    ),Dim[Post Code]))

Regards
Zubair

Please try my custom visuals
Anonymous
Not applicable

Hi Zubair

 

Many thanks for your speedy response.  I have tried the measure and have got the below result:

 

Capture.PNG

 

However this is not quite what I was after.  Please could you have another look?

 

Thank you

 

Chris

 

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.