THE SQL Server Blog Spot on the Web

Welcome to SQLblog.com - The SQL Server blog spot on the web Sign in | |
in Search

SQLBI - Marco Russo

SQLBI is a blog dedicated to building Business Intelligence solutions with SQL Server.
You can follow me on Twitter: @marcorus

Using Added Columns in #DAX Queries

I had an issue in a query that reminded me a few details naming columns created by ADDCOLUMNS.

When you specify a simple name in ADDCOLUMNS, you can use it later, for example in a SUMMARIZE or in a FILTER expression, such as in the following example (see the Value column):

EVALUATE
CALCULATETABLE (
    ADDCOLUMNS (
        ADDCOLUMNS (
            VALUES ( 'Date'[Date] ),
            "Value", [Internet Total Sales]
        ),
        "Frequency", COUNTROWS (
            FILTER (
                VALUES ( 'Date'[Date] ),
                [Internet Total Sales] <= [Value]
            )
        )
    ),
    'Date'[Calendar Year] = 2006,
    'Date'[Month] = 7
)

Naming an added column in this way makes it accessible only through its name, using the “measure” syntax, which doesn’t have a table name before the name of the column (please, remind that this is not a best practice – always use the table name before the column name when you reference a column and always omit the table name when you reference a measure!).

So, a better way to write the previous expression could be the following one:

EVALUATE
CALCULATETABLE (
    ADDCOLUMNS (
        ADDCOLUMNS (
            VALUES ( 'Date'[Date] ),
            "’Date’[Value]", [Internet Total Sales]
        ),
        "Frequency", COUNTROWS (
            FILTER (
                VALUES ( 'Date'[Date] ),
                [Internet Total Sales] <= ‘Date’[Value]
            )
        )
    ),
    'Date'[Calendar Year] = 2006,
    'Date'[Month] = 7
)

Until now, there is nothing really new. It could be just a good reminder. Now, for some reason a few days ago I wrote this:

EVALUATE
CALCULATETABLE (
    ADDCOLUMNS (
        ADDCOLUMNS (
            VALUES ( 'Date'[Date] ),
            "[Value]", [Internet Total Sales]
        ),
        "Frequency", COUNTROWS (
            FILTER (
                VALUES ( 'Date'[Date] ),
                [Internet Total Sales] <= [Value]
            )
        )
    ),
    'Date'[Calendar Year] = 2006,
    'Date'[Month] = 7
)

In this case executing the query you receive an error that says that the Value column is not found. The problem is that I used "[Value]" instead of  "Value". So the lesson is: be careful when you name a column, don’t use square brackets unless you want to include the table name, which is a good idea so you will not confuse its semantic with a measure when you reference such a column later in your expression.

Published Tuesday, January 21, 2014 4:08 PM by Marco Russo (SQLBI)

Comment Notification

If you would like to receive an email when updates are made to this post, please register here

Subscribe to this post's comments using RSS

Comments

No Comments

Leave a Comment

(required) 
(required) 
Submit

About Marco Russo (SQLBI)

Marco Russo is a consultant, writer and trainer specialized in Business Intelligence with Microsoft technologies. He runs the SQLBI.COM website, which is dedicated to distribute resources useful for BI developers, like Integration Services components, Analysis Services models, tools, technical information and so on. Marco is certified as MCT, MCDBA, MCSD.NET, MCSA, MCSE+I.

This Blog

Syndication

Archives

Powered by Community Server (Commercial Edition), by Telligent Systems
  Privacy Statement