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
Erin001
Helper II
Helper II

Ranking and displaying cities of shortest distance

Hi,

I have a data set that contains columns Country, State, City, Location X, Location Y; (X,Y) is the location on the coordinate. So anybody can help me on how to caculate the shortest distance starting from every city to any other instate cities and display those cities(with the first and second shortest distance) in columns?

 

Here's the original data:

 

Original.PNG 

 

and here's what I would like to show: 

 

Result.PNG

 

 

Pre-Appreciated!

 

1 ACCEPTED SOLUTION

Hi @Erin001,

 

Try these two measures, please.

shortestInStateCity =
MINX (
    TOPN (
        1,
        FILTER (
            ADDCOLUMNS (
                CROSSJOIN (
                    ALL ( 'Table1' ),
                    SELECTCOLUMNS (
                        'Table1',
                        "City2", [City],
                        "Country2", [Country],
                        "State2", [State],
                        "X2", [X],
                        "Y2", [Y]
                    )
                ),
                "Distance", SQRT ( POWER ( [X] - [X2], 2 ) + POWER ( [Y] - [Y2], 2 ) )
            ),
            [Distance] <> 0
                && [State] = [State2]
        ),
        [Distance], ASC
    ),
    [City]
)
2ndShortestInStateCity =
MINX (
    TOPN (
        1,
        TOPN (
            2,
            FILTER (
                ADDCOLUMNS (
                    CROSSJOIN (
                        ALL ( 'Table1' ),
                        SELECTCOLUMNS (
                            'Table1',
                            "City2", [City],
                            "Country2", [Country],
                            "State2", [State],
                            "X2", [X],
                            "Y2", [Y]
                        )
                    ),
                    "Distance", SQRT ( POWER ( [X] - [X2], 2 ) + POWER ( [Y] - [Y2], 2 ) )
                ),
                [Distance] <> 0
                    && [State] = [State2]
            ),
            [Distance], ASC
        ),
        [Distance], DESC
    ),
    [city]
)

Ranking-and-displaying-cities-of-shortest-distance

 

Best Regards,

Community Support Team _ Dale
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

6 REPLIES 6
v-jiascu-msft
Employee
Employee

Hi @Erin001,

 

What's the distance? How can we calculate it?

 

 

Best Regards,

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

every city is described as a point(x,y) on the coordinate, and the distance between 2 cities is calculated as D = sqrt((x1-x2)*(x1-x2) +(y1-y2)*(y1-y2)).

 

Thanks!

 

@v-jiascu-msft

Hi @Erin001,

 

Try these two measures, please.

shortestInStateCity =
MINX (
    TOPN (
        1,
        FILTER (
            ADDCOLUMNS (
                CROSSJOIN (
                    ALL ( 'Table1' ),
                    SELECTCOLUMNS (
                        'Table1',
                        "City2", [City],
                        "Country2", [Country],
                        "State2", [State],
                        "X2", [X],
                        "Y2", [Y]
                    )
                ),
                "Distance", SQRT ( POWER ( [X] - [X2], 2 ) + POWER ( [Y] - [Y2], 2 ) )
            ),
            [Distance] <> 0
                && [State] = [State2]
        ),
        [Distance], ASC
    ),
    [City]
)
2ndShortestInStateCity =
MINX (
    TOPN (
        1,
        TOPN (
            2,
            FILTER (
                ADDCOLUMNS (
                    CROSSJOIN (
                        ALL ( 'Table1' ),
                        SELECTCOLUMNS (
                            'Table1',
                            "City2", [City],
                            "Country2", [Country],
                            "State2", [State],
                            "X2", [X],
                            "Y2", [Y]
                        )
                    ),
                    "Distance", SQRT ( POWER ( [X] - [X2], 2 ) + POWER ( [Y] - [Y2], 2 ) )
                ),
                [Distance] <> 0
                    && [State] = [State2]
            ),
            [Distance], ASC
        ),
        [Distance], DESC
    ),
    [city]
)

Ranking-and-displaying-cities-of-shortest-distance

 

Best Regards,

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

@LivioLanzo@v-jiascu-msft

 

It works pretty well, thank you so much!

 

one question about the function Minx(): it is said on the MS DAX doc: 

Return value

A decimal number.

 

https://docs.microsoft.com/en-us/dax/minx-function-dax

 

but it returns the 'City' in my case. 

 

Thanks!

 

 

 

 

 

 

LivioLanzo
Solution Sage
Solution Sage

Hello @Erin001

 

could you show your real dataset?

 

thx

 


 


Did I answer your question correctly? Mark my answer as a solution!


Proud to be a Datanaut!  

sorry, I can't.  The data I posted are similar to my real data.

 

every city is described as a point(x,y) on the coordinate, and the distance between 2 cities is calculated as D = sqrt((x1-x2)*(x1-x2) +(y1-y2)*(y1-y2)).

 

@LivioLanzo

 

 

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.