DAX Queries, Part 1

So at long last Denali CTP3 has been released and I can blog about all the cool new stuff in it. It feels like years (in fact it has been years) since I’ve had anywhere near this much new functionality to learn and discuss here – it’s better than Christmas! And where better to start than with DAX queries? We’ve had DAX calculations for a while now, of course, but now in BISM Tabular mode we can actually write queries in DAX too. Let’s take a look at how the language works…

For the purposes of this post and the others in this series I built a very simple Tabular mode with two tables from the Adventure Works database, DimDate, DimProduct, DimProductSubCategory, DimProductCategory and FactInternetSales.

image

(I know I’ve not talked about how you would actually go about building a Tabular model yet, but this post from the BISM team is a good starting point and in any case it’s not too different from how you’d build a PowerPivot model)

The simplest DAX query we can write on this model is probably this:

evaluate(
FactInternetSales
)

This returns every row and every column from the FactInternetSales table. Here’s what you see when you run this query in an MDX query window (!) in SQL Server Management Studio:

image

As you can see, the Evaluate statement is at the heart of the new DAX query language: it returns the results of a DAX table expression as the results of a query.

We can filter the rows we receive from a query by using the Filter function:

evaluate(
Filter(
FactInternetSales
, FactInternetSales[OrderDateKey]>20030101)
)

image

Here, I’m getting all the columns from FactInternetSales but only those rows where the OrderDateKey is greater than 20030101.

We can also order our resultset by using an Order By clause, for example:

evaluate(
Filter(
FactInternetSales
, FactInternetSales[OrderDateKey]>20030101)
)
order by
FactInternetSales[OrderDateKey] asc,
FactInternetSales[CustomerKey] asc

image

And there’s also a Start At clause where, for every column that appears in the Order By clause, you can specify to start the result set at the first row where a particular set of values appears; I would imagine that this will be useful for pagination in reports. If you compare the results of the following query with the results of the previous query:

evaluate(
Filter(
FactInternetSales
, FactInternetSales[OrderDateKey]>20030101)
)
order by
FactInternetSales[OrderDateKey] asc,
FactInternetSales[CustomerKey] asc
start at
20030104,
23120

image

…you can see that our resultset now starts at the row where OrderDateKey = 20030104 and CustomerKey=23120.

In part 2, I’ll take a look at the Summarize function…

18 thoughts on “DAX Queries, Part 1

  1. HI Chris ,

    Do you think in near future DAX is going to replace MDX ?.. What would be the future of analysis services ?… Does the multidimensional model is going to stop in cming years ?..

    1. That’s the million-dollar question! I’ve given my opinion several times here; I can only say you should read my previous blog posts on the subject (which, incidentally, record my opinions at different points in time and which may not reflect my opinion today or in the future).

  2. Hi Chris

    The “start at” phrase appears to just be another way to filter the data. Have I misunderstood? If not, why would we not just use the Filter function?

    Thanks
    Craig

    1. Good question – I’m not sure if there are any differences between Filter and Start At as far as performance etc goes. I’ll try to find out…

    1. There is no filter clause – Filter() is a function and is by far the more flexible option. The Start At clause is part of the query and is, I guess, something that the devs thought might be useful when creating the language. It may be more efficient than doing the same thing with Filter() but I don’t honestly know.

  3. Great blog thanks, is there anyway of just inserting a table without adding more cruft to the data model? I can copy and paste a table to give me a new one, but there doesn’t appear to be a way to just insert a table connected to the data model.

    Given excel 2016 64bit’s propensity for just deleting the data model when you make changes I’m not keen on adding and deleting lots of tables.

    Thanks in advance,

    Tim

    1. No, there isn’t an easy way to add new Excel tables connected to the Data Model. The latest versions of Excel make it easy to build tables linked to the Power Query queries that feed the tables in the Data Model, but there’s no easy way to build tables bound to DAX queries for some reason.

Leave a Reply to DAX Queries, Part 2 « Chris Webb's BI BlogCancel reply