• Zur Hauptnavigation springen
  • Zum Inhalt springen
  • Zur Seitenspalte springen
  • Zur Fußzeile springen

THE SELF-SERVICE-BI BLOG

Wir lieben Microsoft Power BI

  • Videokurse
    • Coming soon!
  • Live Online Power BI-Schulungen
  • Beratung
    • Was ich für Dich tun kann
    • Showcases
  • Kunden
  • BLOG
    • Business Topics
    • Technical Topics (english)
    • Tools
  • Podcast
  • Kontakt
  • Über

Technical Topics (english) / 29. Januar 2019

Query time periods with CUBE formulas in Excel

If your Excel file contains an Excel data model, you have the possibility to query this data model using so-called CUBE formulas within the Excel cells. This allows a high degree of flexibility when creating Excel reports based on the Excel data model. However, if you are working with Excel and the Excel data model, I hope you are familiar with the following two resources:

  • Mastering the CUBE Functions in Excel 2013 by Peter Myers and
  • Introduction to MDX for PowerPivot users by Chris Webb.

A customer recently asked me how I can query periods from the Excel data model using entries in cells. What he wanted to achieve should look like this:

The desired solution, Power BI, Excel
The desired solution

From my point of view, the solution presented here can be divided into three sub-steps, which I will show below. You can download my example file from here: Download Example file.

Step #1: Reference date values correctly in CUBE formulas

Referencing a date column of the data model within the CUBEVALUE() function did not initially produce a result for me. I got the following message all the time, when trying a syntax like this:

This date reference doesn't return the desired result, Excel, Cube formula
This date reference doesn’t return the desired result

To find the correct syntax, I created a PivotTable from the data model and converted it into CUBE formulas to see how Excel converts it internally. To do this, follow these steps:

  1. Switch to Power Pivot window
  2. Create a PivotTable from the data model (press Home → PivotTable)…
  3. …in a new Worksheet
  4. Drag the field date from the fields pane to the line caption of the PivotTable
  5. Put the Measure Sum Values into the values area
  6. If the rows of the PivotTable are grouped by years, quarters, … expand at least one year, so that you can see a specific day
  7. With the PivotTable selected to Analyze in the ribbon and choose OLAP Tools → Convert to formulas

With the 2nd of January 2008 selected, you can see this formula:

How excel references date values in CUBE formulas, Power BI
How excel references date values in CUBE formulas

The interesting part of the formula is the one marked red. It shows how a date reference should be used in a corresponding CUBE formula. The correct syntax is thus structured as follows: „YYYY-MM-DDThh:mm:ss„, where the time here always contains zero values. If I want to display the value of my measure „Sum Values“ for January 2nd in a CUBEVALUE() formula, the formula could look like this:

Using the correct syntax for date references in my CUBE formula, Power BI
Using the correct syntax for date references in my CUBE formula

So I know at this point how to correctly reference date values in CUBE formulas. But what about periods?

Step #2: Reference seamless time periods in CUBE formulas

The thing about time periods in CUBE formulas is that I can’t create them in Excel logic (via >=/ <=), but have to resort to another CUBE function: On CUBESET(). Since I am not an MDX person, I explain the behavior of the CUBESET() function, related to my example, with my own non-technical words: It let’s me define a (seamless) time period, which I can send to the data model and let’s me retrieve my measure for this time period. A solution for the period January 1st 2018 to May 1st 2018 could look like this:

Referencing time periods in CUBE formulas, Excel, Power BI
Referencing time periods in CUBE formulas

While the first parameter of the CUBESET() function is the connection to the data model, the second parameter let’s me specify the period. The colon is particularly important because it defines a time period from the start value (January 1st 2018) to the end value (May 1st 2018). This function now returns correct values, but is not yet linked to the cells in Excel. I’ll take care of that now.

Step #3: Making the CUBE formula refer to cell entries

Linking the CUBE formula to the Excel cells is not very difficult. But you have to pay attention to the correct formatting of the dates and here I have two possibilities:

  1. I can correctly format the date in the CUBE formula, or
  2. include auxiliary cells.

For didactic reasons I use variant b).

The values in column E refer to the values in column D which are in the ‚ordinary‘ (German) date format which I have to convert to be suitable for the CUBE functions.

Convert a common date format to the required syntax for CUBE formulas, Power BI
Convert a common date format to the required syntax for CUBE formulas

I can now reference these auxiliary cells in my CUBESET() function to make the result react on the entries in cells D4 and D5:

Now the CUBE function reacts as desired to the entries in cells D4 and D5, Power BI, Excel
Now the CUBE function reacts as desired to the entries in cells D4 and D5

I hope this is usefull for one or the other 🙂

Many greetings from Germany,

Lars

Lars Schreiber

Lars ist Berater, Entwickler und Trainer für Microsoft Power BI. Er ist zertifizierter Power BI-Experte und Microsoft Trainer. Für sein Engagement in der internationalen Community wurde Lars seit 2017 jährlich durch Microsoft der MVP-Award verliehen. Lies hier mehr…

Kategorie: Technical Topics (english) Stichworte: Cube formulas, Data model, Excel, MDX, Power Pivot

Leser-Interaktionen

Kommentare

  1. Erik Jonker meint

    9. Juli 2020 um 5:16 pm

    Hi Lars
    Using TEXT(DateValue,“YYYY-MM-DDTHH:MM:SS“) in Excel also works and if you save the format as a Named reference, it is even simpler.

    Regards

    • Lars Schreiber meint

      16. Juli 2020 um 11:12 am

      Hi Erik,

      thanks for the hints.

      Cheers,
      Lars

Seitenspalte

WEBSITE DURCHSUCHEN

MELDE DICH FÜR DIE POWER BI USER GROUP HAMBURG AN

Trage Deine E-Mailadresse ein, um für kommende Treffen der PUG Hamburg eingeladen zu werden. Zudem erhältst Du Zugriff auf die Materialien der vergangenen Treffen.

Footer

Kontakt

THE SELF-SERVICE-BI BLOG
Mail: lars@ssbi-blog.de

Rechtliches

  • Impressum
  • Datenschutz

Über THE SELF-SERVICE-BI BLOG

Ich bin ein freiberuflicher Power BI-Berater, -Entwickler und -Trainer und wurde von Microsoft mehrfach mit dem MVP Award ausgezeichnet. Ich arbeite mit einem kompetenten Netzwerk aus freiberuflichen und ambitionierten Kollegen zusammen. Erfahre hier mehr.

Social

Folge mir...

Copyright © 2025 · Digital Pro on Genesis Framework