DAX Queries, Part 1
Reposted from Chris Webb's blog with the author's permission.
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.
(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:
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)
)
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
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
…you can see that our resultset now starts at the row where OrderDateKey = 20030104 and CustomerKey=23120.
Tune in next time for the Summarize function…
Chris has been working with Microsoft BI tools since he started using beta 3 of OLAP Services back in the late 90s. Since then he has worked with Analysis Services in a number of roles (including three years spent with Microsoft Consulting Services) and he is now an independent consultant specialising in complex MDX, Analysis Services cube design and Analysis Services query performance problems. His company website can be found at http://www.crossjoin.co.uk and his blog can be found at http://cwebbbi.wordpress.com/ . |