How to write queries in DAX to interrogate SSAS tabular models
Part six of an eight-part series of blogs

As well as creating measures to aggregate data in tabular models using DAX, you can also write queries to extract data - this blog shows you how!

  1. Writing DAX queries
  2. DAX and SQL compared
  3. The EVALUATE command in the DAX query language
  4. Using SUMMARIZE to group or aggregate DAX query data
  5. Filtering in DAX queries using CALCULATETABLE or FILTER
  6. Adding columns in a DAX query using ADDCOLUMNS (this blog)
  7. Combining the results of two or more tables
  8. Other useful DAX functions

This blog is part of our online SSAS Tabular tutorial; we also offer lots of other Analysis Services training resources.

Posted by Andy Brown on 12 February 2016

You need a minimum screen resolution of about 700 pixels width to see our blogs. This is because they contain diagrams and tables which would not be viewable easily on a mobile phone or small laptop. Please use a larger tablet, notebook or desktop computer, or change your screen resolution settings.

Adding columns in a DAX query using ADDCOLUMNS

You can include ad hoc calculations in a DAX query by creating measures on the fly using the ADDCOLUMNS function:

ADDCOLUMNS(

Table whose columns you want to display,

Name for the first added column,
Calculation expression for this column,

...,

Name for the last added column,
Calculation expression for this column

)

This function is equivalent to adding a calculated column to a table; the only real difference is that ad hoc columns are calculated only once (they're not stored in your model).

An example: counting rows

The following query shows how many transactions there have been for each species:

EVALUATE

ADDCOLUMNS (

Species,

"Number transactions",

COUNTROWS ( RELATEDTABLE ( 'Transaction' ) )

)

This query will show the columns from the Species table, then an additional column giving the number of rows there are for each species in the related Transaction table, to give:

The query results

The output from running this query: the two columns SpeciesId and SpeciesName, and the new derived column Number transactions.

 

An example: transaction statistics by town

In this example, we show all of the columns from the Town table, plus 3 other derived statistics: 

EVALUATE

ADDCOLUMNS (

Town,

-- show the average value of transactions

"Average value",

AVERAGEX (

RELATEDTABLE ( 'Transaction' ),

'Transaction'[Price] * 'Transaction'[Quantity]

),

-- the total value of transactions

"Total value",

SUMX (

RELATEDTABLE ( 'Transaction' ),

'Transaction'[Price] * 'Transaction'[Quantity]

),

-- the number of transactions

"Number rows",

COUNTROWS (

RELATEDTABLE ( 'Transaction' )

)

)

ORDER BY

Town[TownName]

Here's what this would show (at least, the first few rows):

The transaction statistics

The 3 new calculations for each row of the Town table.

Defining measures within a DAX query

Another way to create ad hoc calculations is to define them first using the DEFINE MEASURE command. For example, you could rewrite the above query as:

-- measures to show the average value

-- of transactions, the total value and the

-- number of transactions

DEFINE

MEASURE 'Town'[Average value] =

AVERAGEX (

RELATEDTABLE ( 'Transaction' ),

'Transaction'[Price] * 'Transaction'[Quantity]

)

 

MEASURE 'Town'[Total value] =

SUMX (

RELATEDTABLE ( 'Transaction' ),

'Transaction'[Price] * 'Transaction'[Quantity]

)

MEASURE 'Town'[Number rows] =

( COUNTROWS (

RELATEDTABLE ( 'Transaction' ) )

)

-- now show these measures

EVALUATE

ADDCOLUMNS (

Town,

"Average value",

Town[Average value],

"Total value",

Town[Total value],

"Number rows",

Town[Number rows]

)

ORDER BY

Town[TownName]

The query above would give exactly the same result:

Statistics by town

Different query, same result.

The main reason to pre-declare your measures like this is so that you can reference them more than once in your EVALUATE statement.

I think it's fair to say that I've now finished showing the most common DAX commands.  What we'll do now is look at how you can combine tables, using functions like GENERATE and GENERATEALL.

This blog has 0 threads Add post