564 attributed reviews in the last 3 years
Refreshingly small course sizes
Outstandingly good courseware
Whizzy online classrooms
Wise Owls only (no freelancers)
Almost no cancellations
We have genuine integrity
We invoice after training
Review 30+ years of Wise Owl
View our top 100 clients
Search our website
We also send out useful tips in a monthly email newsletter ...
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!
This blog is part of our online SSAS Tabular tutorial; we also offer lots of other Analysis Services training resources. |
You can include ad hoc calculations in a DAX query by creating measures on the fly using the ADDCOLUMNS function:
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).
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 output from running this query: the two columns SpeciesId and SpeciesName, and the new derived column Number transactions.
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 3 new calculations for each row of the Town table.
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:
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.
Parts of this blog |
---|
|
Some other pages relevant to the above blogs include:
Kingsmoor House
Railway Street
GLOSSOP
SK13 2AA
Landmark Offices
99 Bishopsgate
LONDON
EC2M 3XD
Holiday Inn
25 Aytoun Street
MANCHESTER
M1 3AE
© Wise Owl Business Solutions Ltd 2023. All Rights Reserved.