Forum Discussion

Chris_Gross's avatar
Chris_Gross
Icon for Microsoft rankMicrosoft
Dec 03, 2020

LAMBDA Examples: Distance between two cities

This post is the first of a series where we will be sharing out examples of lambdas. This is intended to highlight lambdas we have cooked up that show the power of this new super-charged function. Additionally, you have the opportunity to engage with us on the lambdas you have built yourself and of course let us know how our own formulas could be improved. 

 

If you didn’t catch the announcement, be sure to check out the blog post highlighting the release of this new function, Announcing LAMBDA: Turn Excel formulas into custom functions

 

In today’s example we will be picking up where we left off in the announcement blog and making good on the promise of:

 

“a custom function that takes two cities as input and calculates the distance between them...”

 

So let’s get to it!

 

Distance between two cities

The first thing to note is that this function will be making use of Excel Data Types. Data Types are useful here because of the ease at which we can retrieve latitude and longitude for a given entity through “dot notation”.

 

Property Extraction

 

The next thing to cover is the mathematical formula which we will be encoding as an excel formula. We will be making use of the law of cosines which can give you an as the crow flies distance calculation.

 

This formula is a great one to encode as a lambda given its complexity which will make it more prone to formula-authoring errors. It also happens to re-use multiple inputs which makes it a great candidate for LET. In short, this is the type of function I would want to author once and store for re-use.

 

The equation looks like this:

law of cosines

 

While this might seem a bit daunting, the inputs we really care about are:

  1. Latitude and longitude of the start location
  2. Latitude and longitude of the end location

In the equation

  • Δλ is the delta of the longitudes (_lon2 - _lon1)
  • φ1 and φ2 represent _lon1 and _lon2 respectively
  • r is equal to the radius of the sphere, in this case 6378 which is the radius of the earth in kilometers.

The last trick we employ in this example is to convert everything into radians which is where we make use of the LET function to do these transformations. This is important as the equation expects lat/long in radians and the Data Types return them in degrees.

 

This is illustrated in the first series of name definitions where we:

  1. Calculate the values in terms of radians for re-use
  2. Assign new names to differentiate between the input values (_lat1, _lon1, _lat2, _lon2) and transformed values (lat_1, lat_2, lon_1, lon_2)

Putting all those concepts together gives us the following solution for LATLONGDISTANCE which will be doing the heavy-lifting for the final formula that takes in cities and passes in their respective latitudes and longitudes to LATLONGDISTANCE.

 

=LATLONGDISTANCE

=LAMBDA(_lat1, _lon1, _lat2, _lon2, LET(
lat_1, RADIANS(_lat1),
lon_1, RADIANS(_lon1),
lat_2, RADIANS(_lat2),
lon_2, RADIANS(_lon2),
r, 6378,
ACOS(
(SIN(lat_1) * SIN(lat_2)) + (COS(lat_1) * COS(lat_2) * COS(lon_2-lon_1))
) * r
))

 

=ASTHECROWFLIES

The last piece of the puzzle is to create a lambda which will take two cities as inputs. You could encode all of this into the previous formula, but we like the composability of lambdas and figured it would be a great way to show lambdas calling one another.

 

Revisiting the previous comment, about extracting properties from data types, we will need to define something which takes two cities as inputs and then extracts the latitudes and longitudes.

 

For this we will make use of dot notation and LET.

=LAMBDA(city1, city2, LET(
lat_1, city1.Latitude,
lon_1, city1.Longitude,
lat_2, city2.Latitude,
lon_2, city2.Longitude,
))

With the values extracted and names defined, the last thing to do is define a calculation which we call distance that returns the value. You’ll notice we wrap this in an IFERROR to catch any errors which might result from passing in bad values.

 

=LAMBDA(city1, city2, LET(
lat_1, city1.Latitude,
lon_1, city1.Longitude,
lat_2, city2.Latitude,
lon_2, city2.Longitude,
distance, LATLONGDISTANCE(lat_1, lon_1, lat_2, lon_2),
IFERROR(distance, "an error occurred")
))

 

And that's it!

 

ASTHECROWFLIES

 

We hope you found this example useful and look forward to seeing what lambdas you have cooked up on your own.

 

Until next time!

 

Chris Gross,

Program Manager Excel

Resources