Creating Power Query Functions

Editor’s note: The following post was written by SQL Server MVP Rafael Salas

Creating Power Query Functions

You have seen or started using Power Query for Excel by now. If not you have been missing one of the greatest tools of the new Self-Service Business Intelligence offering Power BI.

Power Query has a wide range of options to discover, extract and manipulate data from internal and external sources via a very friendly user interface and you can go a long way with little to no programing. However, you are also given the choice of creating queries from scratch using M language in those situations where the requirements go beyond of the functionality provided by the user interface.

In this post, I want to show you how you can create parameterized functions that can be later be referenced and re-used by other Power Queries. This is something that can come handy when you want to wrap complex logic that end users may not be able to write themselves or when dealing with a piece of logic that is frequently used.

A Simple Scenario for a function: Formatting Dates

For this first example, let’s start with a simple scenario where we need to ensure that date values are formatted as MM/DD/YYYY and ensure that the month and day portions have leading zeros; so a value of 8/5/2010 should be represented as 08/05/2010 and so on.

We will use a dataset from and Excel table with a list of conferences along with their dates and location information. As you can see in the Figure 1, the date values does not have the required leading zeros in the month and day parts.

image

Creating a Baseline Query for Our Function

Since we are not familiar yet with M language we are going to format the dates by using the options provided by the user interface and then use the generated code as baseline for a function.

1. Click any cell within the table and create a new Power Query. Power Query –> From Table

2. When the Query Editor window opens, right-click in any of the columns and select: Insert Column –> Custom as shown in Figure 2

image

3. When the Insert Custom Column editor opens, enter the following M code and click OK

     Text.PadStart(Text.From(Date.Month([EventDate])),2,"0") & "/" &

     Text.PadStart(Text.From(Date.Day([EventDate])),2,"0") & "/" 

     &Text.From(Date.Year([EventDate]))

Note: We will use this snippet of M code later on to create our function. See Microsoft Power Query For Excel Formula Library Specification document for more information about the function used here and learn more about M language.

image

4. Back in the query editor, we should now have a new column called “custom” that displays the date values properly formatted as text. Click done to close the query editor and see the results of the query in a new Excel sheet.

image

Creating the Function

Now imagine users need to reformat date values as previously shown in a regular basis. We will create a function that takes a date value as input parameter (InDate) and returns a date as text with the appropriate format using the expression from step 3.

5. Create a new Power Query. Power Query –> From Other Sources –> Blank Query

6. When the query editor opens, click the Advanced Query editor button as shown in the figure below. Note: Advance query editor is disable by default, to enable it click options in the Power Query menu and check the Enable advanced query editing option.

7. Change the query as follows and click done (see Figure 6):

a. Replace the double quotes in the “source” expression with the expression from step 3 above. Then, parameterize the expression by replacing the “EventDate” field with “InDate” string.

b. Add an outer let…in expression with an input date parameter called “InDate”.

c. Rename the query to fFormatDate

The query should look like this:

let

     FormatDate = (InDate as date) =>

let

       Source = Text.PadStart(Text.From(Date.Month(InDate)),2,"0") &

       "/" & Text.PadStart(Text.From(Date.Day(InDate)),2,"0") & "/"

       &Text.From(Date.Year(InDate))

in

      Source

in

      FormatDate

image

Once you click Done, the query editor is able to recognize our query as a parameterized function as shown in the figure below. Click Done to exit the editor, and if you have not gotten any errors your function is ready to be used. Note: you should be able to test the function with a single input value by using the Invoke button, but you would need to delete the “Invoke<fnName>” step that is added to the query before exiting the query editor.

image

Calling a Function

Now that our function has been created, we should be able to call it from other queries within the workbook. We will use a copy of the query we built at the beginning with the list of events and dates.

8. Go to the worksheet that has the query we created in steps 1 through 4, click on any cell and click the Filter & Shape option in the Query Settings pane or under the Query menu in the ribbon.

9. One the query editor opens and if necessary, change the type of the EventDate column to Date so it matches the data type of the input parameter of our function. Select EventDate column->right-click->Change Type->Date

10. Now we will add a new column that use the function we just created to reformat the values in EventDate. Select any column->Right-click->Insert Column->Custom

11. Once the Insert Custom Column editor opens, paste the following code to invoke the function and pass the EventDate values as parameter. Click OK.

       fFormatDate([EventDate])

       image

As you can see, the function is executed for every record in the record set.

image

Few notes about M and Power Query Functions

· M language is case sensitive, so make sure that both spelling and casing are correct when troubleshooting your code.

· The scope of a function is the workbook on which it is contained, so you would need to re-create functions on each workbook where they are needed.

· There is no easy way to discover or search for custom functions within an Excel file. This may pose a challenge when dealing with workbooks with many worksheets.

· There is no Intellisense for M which makes and you have to resort to the language and library specification documents.

Wrapping it up

As you can see, we have the ability to use functions as a way to encapsulate pieces of logic that can later be referenced from other power queries in the workbook giving us greater flexibility when creating more complex queries, or breaking a large query into smaller and more manageable pieces. You can also use function to abstract calls to external data sources such as APIs or to break complex queries into more manageable units of code.

Preview version warning – this information is current for Power Query preview (Version: 1.5.3296.1161). The information contained in this article may change prior to RTM.

 

About the author

Foto_Rafael_profile_1_-_small

Rafael is a speaker, published authored and blogger with +15 years of relevant IT experience across multiple industries.  He specializes in Business Intelligence and information architecture and is the recipient of multiple industry awards, including Microsoft Most Valuable Professional (MVP) and The Data Warehouse Institute best practices.  Rafael is also an active member in the SQL Server technical community and maintains a blog at www.rafael-salas.com.  Follow him on Twitter.

About MVP Monday

The MVP Monday Series is created by Melissa Travers. In this series we work to provide readers with a guest post from an MVP every Monday. Melissa is a Community Program Manager, formerly known as MVP Lead, for Messaging and Collaboration (Exchange, Lync, Office 365 and SharePoint) and Microsoft Dynamics in the US. She began her career at Microsoft as an Exchange Support Engineer and has been working with the technical community in some capacity for almost a decade. In her spare time she enjoys going to the gym, shopping for handbags, watching period and fantasy dramas, and spending time with her children and miniature Dachshund. Melissa lives in North Carolina and works out of the Microsoft Charlotte office.