Blog Post

Excel Blog
8 MIN READ

Announcing LAMBDA Helper Functions: Lambdas as arguments and more

Chris_Gross's avatar
Chris_Gross
Icon for Microsoft rankMicrosoft
Jul 26, 2021

Today we are releasing to our Beta customers seven new LAMBDA functions. These functions aid in the authoring of re-usable LAMBDA functions while also serving as stand-alone functions themselves. Additionally, we are sending the LAMBDA function to Current Channel Preview.

 

LAMBDA as arguments – One exciting addition to Excel’s formula language is that LAMBDA is now exposing the ability to be treated as an accepted value type with the addition of new functions. This is an important concept which has existed across many programming languages and is tantamount to the concept of lambda functions in general.

 

LAMBDA to Current Channel Preview – With this latest set of updates we are progressing the LAMBDA function to customers who are a part of the Current Channel Preview audience. In addition we are also introducing the ability to define optional arguments.

 

Lambdas as Values

Before diving into the new functions and how they work, it’s important to understand the concept of functions as values.


Over the past couple years, we have been teaching Excel how to understand new types of values. Some of the most recent additions have been Data Types (Wolfram, Geography, Stocks, Power BI, and even Power Query can create Data Types), and Dynamic Arrays. Lambdas continue this journey by allowing Excel to understand functions as a value. This was enabled by the introduction of LAMBDAs but not exposed to any functions.


This is exciting, because it means that things which were previously impossible, near-impossible, or arduous can now be achieved by writing a LAMBDA and passing it as a value to a function.


For example, imagine you had a constantly growing list of values and needed to generate a list of booleans which check for values that are both greater than 50 but less than 80.

 

You could author one function for each value which checks the condition but this is error prone and requires a lot of duplication for something pretty basic. For reference, the duplicated formulas might look like this (with one formula for each value):

 

=AND(A2>50, A2<80)
=AND(A3>50, A2<80)
...

This is the type of scenario where LAMBDAs can be applied and more specifically, a great example of where to use the new MAP function.

 

MAP

With MAP, you can easily author a LAMBDA which applies a formula to every value and returns the result. MAP’s superpower is value transformation.

 

There are a few new concepts which we will cover shortly, but the formula looks like this:

 

=MAP(Table1[Values],LAMBDA(value, AND(value>F2, value<F3)))

The result is an array of boolean values, corresponding to the values in the Table:

 

With just one formula, you can achieve something pretty powerful! Let’s pause to understand what’s going on.

 

How the functions work

The new MAP function takes one (or many) array/range references and passes each value from the supplied array/ranges as a parameter to the LAMBDA function (in this case Table1[Values]). The fact that LAMBDA expects parameters from MAP is an important concept to remember as you check out each of the new functions, since it’s different for each one.


In our case we have one array, so the LAMBDA is pretty simple, and expects only one parameter.


Focusing in on the LAMBDA itself, you can see that in this example we chose to call our single parameter “value”, but you can call it by any legal parameter name:

 

LAMBDA(value, AND(value>F2, value<F3))

Another key concept to understand, with these new functions, is that the power comes from the fact that Excel will do a calculation for each value supplied and then make LAMBDA do the heavy lifting. In this particular case it will return an array of results but there are other functions we are introducing today which will return only one value.

 

REDUCE

While MAP proves useful for transforming a list of values, let’s say that we wanted to count how many items met the condition.


This is where REDUCE comes in handy and is a perfect opportunity to talk about the second function on our list.


This time, we are going to re-use the same logic as before but wrap the calculation in an IF to do our counting. The formula is rather simple, like before, being that we only need one function call:

 

=REDUCE(Table1[Values], LAMBDA(accumulator, value,
     IF(AND(value>F2, value<F3), 1 + accumulator, accumulator)
))

 REDUCE does, hopefully, what it sounds like. It reduces a list of values into one value by making use of a LAMBDA.

 

The major difference with REDUCE is that it makes use of two parameters in its LAMBDA value:

  • accumulator: The initial value returned by REDUCE and each LAMBDA call.
  • value: A value from the supplied array

The other thing to note is the first, optional argument, which is the [initial value] for the accumulator. In our case we want it to be 0.


The accumulator is what allows us to write our own custom aggregation-IF function (you can even write PRODUCTIF with REDUCE) and can be seen if you focus on the calculation portion of the LAMBDA:

 

IF(AND(value>F2, value<F3), 1 + accumulator, accumulator)

The final result, in my opinion, is elegant and self-contained.

 

BYROW & BYCOL

The next two functions which we are introducing are BYROW and BYCOL. These functions take an array or range and call a lambda with all the data grouped by each row or column and then return an array of single values. Hence the name.


These two functions are great because they allow for calculations which were previously impossible because they would produce arrays of arrays.


For example, lets imagine we had some data which tracked the temperature for every day of a week. We are interested in seeing days where the average temperature for the week is greater than 85 degrees Fahrenheit.

 

Without BYROW, we would need to create a helper column and calculate averages using a bunch of formulas and then likely use filter UI or some other wizardry.


With BYROW, we can author a LAMBDA which meets our constraints and then pass the result to the FILTER function.


This is great because as we add new data week over week, our calculations are set and we don’t have to reauthor our workbook.


The formula looks like this:

 

=FILTER(Table3, BYROW(Table3, LAMBDA(week, AVERAGE(week)>85)))

 

And upon execution, we can quickly see which weeks were extra hot!

 

Now, let’s suppose, we wanted to see this data in Celsius. We can make a quick update and get results in degrees Celsius by wrapping our call with a MAP and make use of CONVERT.

 

=MAP(FILTER(Table3, BYROW(Table3, LAMBDA(week, AVERAGE(week)>85))), LAMBDA(value, IF(ISNUMBER(value), CONVERT(value, "F", "C"), value)))

 

Complete list of functions

While I could create examples for days, I can’t possibly include everything in one post and our documentation does a great job of explaining the specifics of each function, so be sure to check them all out!

 

Name

Description

Argument

Argument

Argument

LAMBDA_Param(s)

MAP

Returns an array formed by “mapping” each value in the array(s) to a new value by applying a lambda to create a new value.

array1: An array to be mapped.

lambda_or_array:

A LAMBDA which must be the last argument and must have a parameter for each array passed, or another array to be mapped.

 

[lambda_or_array…]: A LAMBDA which must be the last argument and must have a parameter for each array passed, or another array to be mapped.

 

array1: A value from array1

 

[array2…]: A value from an additional array. 

REDUCE

Reduces an array to an accumulated value by applying a LAMBDA function to each value and returning the total value in the accumulator.

[initial_value]:

Sets the starting value for the accumulator.

 

 

array: An array to be reduced.

lambda: A LAMBDA that is called to reduce the array. The LAMBDA takes two parameters, accumulator and value.

 

accumulator: The returned value from LAMBDA

 

value: A value from array. 

SCAN

Scans an array by applying a LAMBDA  to each value and returns an array that has each intermediate value.

[initial_value]:

Sets the starting value for the accumulator.

 

array: An array to be scanned.

lambda: A LAMBDA that is called to scan the array. The LAMBDA takes two parameters, accumulator and value.

accumulator: The returned value from LAMBDA

 

value: A value from array. 

MAKEARRAY

Returns a calculated array of a specified row and column size, by applying a LAMBDA function.

rows: The number of rows in the array. Must be greater than zero.

 

cols: The number of columns in the array. Must be greater than zero.

 

lambda: A LAMBDA that is called to create the array. The LAMBDA takes two parameters, row_index and column_index.

 

row_index: The index of the row.

 

column_index: The index of the column.

BYROW

Applies a LAMBDA to each row and returns an array of the results.

array:

An array to be separated by row.

[lambda]:

A LAMBDA that takes a row as a single parameter and calculates one result.

 

value: A value from array. 

BYCOL

Applies a LAMBDA to each column and returns an array of the results.

array:

An array to be separated by column.

[lambda]:

A LAMBDA that takes a column as a single parameter and calculates one result.

 

value: A value from array. 

ISOMITTED

Checks whether the value is missing, and returns TRUE or FALSE.

argument: Is the value you want to test, such as a LAMBDA parameter.

 

 

 

 

 

LAMBDA Improvements

The last thing to cover is the set of improvements we have made to the LAMBDA feature in general. As aforementioned, we are sending LAMBDA to Current Channel Preview and have added support for Optional Parameters in both Current Channel Preview and Insiders: Beta.

 

Optional Parameters

LAMBDA now supports optional parameters. To make use of optional parameters, all you need to do is wrap the optional name in “[]”.

 

For example:

=LAMBDA(param1, [param2], IF(ISOMITTED(param2), param1, param2))

 

This lambda will return the value of param1 if param2 is omitted and otherwise return the value of param2.

 

Try it yourself

If you are in our Beta or Current Channel Preview program, you can try out LAMBDAs yourself. We’d love your feedback as we continue to improve on this new capability.


The new LAMBDA functions are available to 50% of the channel today and over the coming weeks we will increase the flight, pending no bugs or other issues.

 

Note: The LAMBDA function is available to members of the Current Channel Preview program running Windows and Mac builds of Excel. The LAMBDA helper functions are available to members of the Insiders: Beta program running Windows and Mac builds of Excel

 

Join the Office Insider Program and choose the Beta or Current Channel Preview to get early access to LAMBDA in Excel.  Send us feedback via send a smile, or post in the Excel Tech Community.

 

Stay connected with us.  Join our Excel Tech Community.  Let us know what you think, and we’d love to see what you build with LAMBDA!

 

Availability

The new LAMBDA functions are now available to Office Insiders running Beta Channel Version 2108 (Build 14312.20008) or later on Windows, or Version 16.52 (Build 21072100) or later on Mac.

 

The LAMBDA function is now available to Office Insiders running Current Channel Preview Version 2107 (Build 14228.20154) or later on Windows, or Version 16.51 (Build 21071100) or later on Mac.

 

Learn More

To learn more about LAMBDA and the new functions, check out our accompanying post on the Insiders blog which highlights some of the other functions or the help topics below.

 

LAMBDA Help

New LAMBDA Functions

 

Updated Jul 26, 2021
Version 7.0

60 Comments

  • lori_m's avatar
    lori_m
    Iron Contributor

    I found myself looking back at this thread following the recent 'function names as arguments' update. The update addresses some of the earlier comments in this thread - maybe we should now drop the 'LAMBDA' and just call these 'helper functions' ?!

     

    A number of other comments in this thread related to working with arrays of results to which I'm not aware of any satisfactory solution as yet. As I see it, a couple of additional helper functions could solve this need such as APPLY/ACCUMULATE similar to MAP/SCAN but which also importantly are able to stack results by row/col.

  • sanjibdutta's avatar
    sanjibdutta
    Brass Contributor

    Another thought I couldn't resist to share here is that what is going to happen to our hard learnt Excel skill if Microsoft bring ChatGPT right into Excel, a high possibility since MS is controlling ChatGPT. Would this skill be completely superseded by AI? If just throwing a question to ChatGPT bring the right formula or an analytic result at fingertips then what is the use of learning so many functions and features?I guess MS has already brought a flavour of ChatGPT in "Analyze Data" feature. Whatever may be the case, I believe knowledge of Excel capabilities would go a long way to speed up framing the right question to get more accurate results. Any thoughts please..Thanks

  • sanjibdutta's avatar
    sanjibdutta
    Brass Contributor

    One question just appeared in my mind why Googlesheet like Query function that utilizes universal and intutive SQL language is not available in Excel. Google has copied almost all excel function in googlesheet then why microsoft is not introducing this Query function which is so versatile and covers many excel functions in a sigle function. Someday I would like to try to write such function using lambda when I get a chance. But that would be much involving as it would require writing SQL parser. Of course, It may not be much performant..Any thoughts please...Thanks

  • sanjibdutta's avatar
    sanjibdutta
    Brass Contributor

    PeterBartholomew1 

     

    I expected a question like yours.Thanks for asking. I have rewritten them just to check capabilities of Lamda and hone my skill with Lamda. As you pointed out correctly I do believe that using the native ones would achive the highest performance as they might be written in c/c++ or other native language. But I belive that such excercises and resultant skill would help writing Lambda function to address various use cases in addition to tailoring existing function according to special requirement.

     

    It's great to hear your work on Fast Fourier Transform algorithms. I do believe that Let function is a great addition to excel.

     

    Thanks

     

  • sanjibdutta 

    I am sure you are correct, but I am mystified as to why you should wish to rewrite Map, Reduce, Scan, ByCol, ByRow using Lambda recursive functionality.   I believe the helper functions to be more computationally efficient and easier to use than recursion.  The present implementations of Map, Scan, ByCol/Row do have a major shortcoming in that they do not return nested arrays (that is, most solutions of interest) but the workaround is to use REDUCE with V/HSTACK being used to build the 2D nested arrays.

     

    As you point out, the LET function, with its local variables, is a key element of writing code with any significant breadth of functionality.  For example, I have written formulas implementing Fast Fourier Transform algorithms, both using recursion and Lambda helper functions.  The latter version is both more efficient and easier to follow, though the mathematics behind each is not for the fainthearted. 

  • sanjibdutta's avatar
    sanjibdutta
    Brass Contributor

    Lambda is so powerfull that we can rewrite Map,Reduce,Scan,ByCol,ByRow (probably most of excel functions) using Lambda recursive function. MakeArray does not need recursive call. Lambda with "Let" function allow us to rewite moderately long VBA function as function to be used in formula. I am really eager to see features of accessing lambda name within lambda, lambda with varargs, machine global lambda and sharing lambda accross machine..Thanks

  • sanjibdutta's avatar
    sanjibdutta
    Brass Contributor

    I think addition of following two more features would enhance LAMBDA function very much.

    1)Availability of a meta name of the lambda function would allow making recusive call inside Lambda function using that meta name which would allow test and use of recusive lambda as inline formula(not using a name in name manager)

    2)Enabling varargs ( allowing variable number of arguments ) would allow to create many beautiful function that would cover many use cases.

    Thanks

  • SergeiBaklan's avatar
    SergeiBaklan
    Diamond Contributor

    Viz , as a comment. "...if the row array is a range or a variable....". Row is always an array, even if such array has only one element.

  • Viz's avatar
    Viz
    Brass Contributor

    Chris_Gross I seem to have encountered a bug in the ByRow function where it gives two different answers dependng on if the row array is a range or a variable.

     

    Here it is in a nutshell:

     

    I am trying to get moving average using ByRow and index function. I needed sequence number for my algorithm to work. If I keep those sequence numbers in a cell range and refer to that in the ByRow() function, I get correct answers. But if I use the sequence number directly inside ByRow, it is giving slightly wrong answers.

     

    It is detailed more in this post. And in the post I have also attached the post I have used.