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
SCHAPELM
New Member

Calculation distance between latitudes & Longitudes

I currently want to calculate the distance between two sites based on the lattitude & longitude. The lattitude & longitude are currently contained within the table listed against each site.

 

How i want it to work

 

Step 1: Select Site 1

Step 2:Select Site 2

= Result Distance between site 1 & 2

 

 

I need help in creating the two measures required for step 1 & step 2 then writing the equasion for the result.

 

I know the calculation to to work out the distance is:
 =acos(sin(lat1)*sin(lat2)+cos(lat1)*cos(lat2)*cos(lon2-lon1))*6371


Im new to power BI but fluent in tableau so i know how it should work in that format but new to DAX

 

Thanks 
Matt

1 ACCEPTED SOLUTION

@SCHAPELM 
Thank you.

Please refer to attached sample file with the proposed solution

1.png2.png

Distance = 
VAR FromSite = SELECTEDVALUE ( 'Site From'[From Site] )
VAR FromTable = FILTER ( 'Table', 'Table'[SiteDescription] = FromSite )
VAR FromLatitude = MAXX ( FromTable, 'Table'[Latitude] )
VAR FromLongitude = MAXX ( FromTable, 'Table'[Longitude] )
VAR ToSite = SELECTEDVALUE ( 'Site To'[To Site] )
VAR ToTable = FILTER ( 'Table', 'Table'[SiteDescription] = ToSite )
VAR ToLatitude = RADIANS ( MAXX ( ToTable, 'Table'[Latitude] ) )
VAR ToLongitude = RADIANS ( MAXX ( ToTable, 'Table'[Longitude] ) )
RETURN 
    ACOS ( 
        SIN ( FromLatitude ) * SIN ( ToLatitude ) 
            + COS ( FromLatitude ) * COS ( ToLatitude ) * COS ( ToLongitude - FromLongitude ) 
    ) * 6371

View solution in original post

6 REPLIES 6
F_88
Frequent Visitor

Dear all,

 

i replied your code on my project in order to obtain the distance in kilometers. Unfortunately, the result is not accurate. Is it a data latitud/longitud problem? I'm affraid not bcs I tested it on a website and it recognized the kilometer distance correctly.

 

Brief:

- on my original database i had repeated coordinates several times since each row is a zipcode;

- I named my site1 as "origem" and remove duplicated coordinates;

- I named my site2 as "destination" and remove duplicated coordinates;
- "admin name3" is location name;
- i already testing removing duplicates in original database but nothing changed;


my measure is:

Distance =
VAR FromSite = SELECTEDVALUE ( Origem[admin name3] )
VAR FromTable = FILTER ( 'Origem', 'Origem'[admin name3] = FromSite )
VAR FromLatitude = MAXX ( FromTable, 'Origem'[Latitude] )
VAR FromLongitude = MAXX ( FromTable, 'Origem'[Longitude] )
VAR ToSite = SELECTEDVALUE ( Destino[admin name3] )
VAR ToTable = FILTER ( 'Destino', 'Destino'[admin name3] = ToSite )
VAR ToLatitude = RADIANS ( MAXX ( ToTable, 'Destino'[Latitude] ) )
VAR ToLongitude = RADIANS ( MAXX ( ToTable, 'Destino'[Longitude] ) )
RETURN
    ACOS (
        SIN ( FromLatitude ) * SIN ( ToLatitude )
            + COS ( FromLatitude ) * COS ( ToLatitude ) * COS ( ToLongitude - FromLongitude )
    ) * 6371


Could someone help me? I'm not getting why kilometeres are incorrect. Is due tables relationship? i kept it without any connection as you showed on your summary.

 

Thank you in advance
 

SCHAPELM
New Member

Hi @tamerj1 
Thankyou for this,
just curious as I have plotted all my sites on a map (over 500) is it possible to use the map to autoselect  'Site 1' & 'Site 2' fields in the equasion
In essence you select site 1 from the map, then select site 2 and a card displayed on the report would show the distance. Understand if this is too complex

cheers

@SCHAPELM 
Please see attached modified sample file

1.png

Distance = 
IF ( 
    COUNTROWS ( VALUES ( 'Table'[SiteDescription] ) ) = 2,
    VAR FromTable = TOPN ( 1, 'Table', 'Table'[SiteDescription], ASC )
    VAR Lat1 = RADIANS ( MAXX ( FromTable, 'Table'[Latitude] ) )
    VAR Lon1 = RADIANS ( MAXX ( FromTable, 'Table'[Longitude] ) )
    VAR ToTable = TOPN ( 1, 'Table', 'Table'[SiteDescription] )
    VAR Lat2 = RADIANS ( MAXX ( ToTable, 'Table'[Latitude] ) )
    VAR Lon2 = RADIANS ( MAXX ( ToTable, 'Table'[Longitude] ) )
    RETURN 
        ACOS ( 
            SIN ( Lat1 ) * SIN ( Lat2 ) 
                + COS ( Lat1 ) * COS ( Lat2 ) * COS ( Lon2 - Lon1 ) 
        ) * 6371,
    "Select two locations"
)
SCHAPELM
New Member

Hi @tamerj1 
the latitude and longitude are in seperate columns within the table against each site

below is an example of how it is presented

 

SiteDescriptionLatitudeLongitude
Site 1-49.22121.86
Site 2-38.04140.67
Site 3-38.00140.71
Site 4-37.94140.73
Site 5-37.9140.56

@SCHAPELM 
Thank you.

Please refer to attached sample file with the proposed solution

1.png2.png

Distance = 
VAR FromSite = SELECTEDVALUE ( 'Site From'[From Site] )
VAR FromTable = FILTER ( 'Table', 'Table'[SiteDescription] = FromSite )
VAR FromLatitude = MAXX ( FromTable, 'Table'[Latitude] )
VAR FromLongitude = MAXX ( FromTable, 'Table'[Longitude] )
VAR ToSite = SELECTEDVALUE ( 'Site To'[To Site] )
VAR ToTable = FILTER ( 'Table', 'Table'[SiteDescription] = ToSite )
VAR ToLatitude = RADIANS ( MAXX ( ToTable, 'Table'[Latitude] ) )
VAR ToLongitude = RADIANS ( MAXX ( ToTable, 'Table'[Longitude] ) )
RETURN 
    ACOS ( 
        SIN ( FromLatitude ) * SIN ( ToLatitude ) 
            + COS ( FromLatitude ) * COS ( ToLatitude ) * COS ( ToLongitude - FromLongitude ) 
    ) * 6371
tamerj1
Super User
Super User

Hi @SCHAPELM 
How do you have the locations in your data?
Do you have the latitude and longitude in separate columns or together in one column? please present a sample

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.

Top Solution Authors