Yesterday I answered to a question related to parameters in DAX that could be useful to other readers who use DAX in Reporting Services (SSRS): how to manage missing parameters of a DAX query?

I wrote an article in the past describing how to use parameters in a DAX query, but what is not intuitive is that parameters are always strings. Thanks to automatic conversion of data type in DAX, a string can be easily converted into a number, so you do not see any difference until you have to manage the missing value. You might think that the missing value is passed as a blank, but this is not the case. For example, consider the following DAX query.

EVALUATE
CALCULATETABLE (
    'Product',
    'Product'[Unit Price] > @PriceLimit
)

If the DAX query references a parameter (@PriceLimit) that is missing in the query request, you get an error.

The query contains the ‘PriceLimit’ parameter, which is not declared.

Therefore, the XMLA request must include the PriceLimit parameter. Skipping a parameter means sending a similar request:

<Execute xmlns="urn:schemas-microsoft-com:xml-analysis">
    <Command>
        <Statement>
            EVALUATE
            CALCULATETABLE (
                'Product',
                'Product'[Unit Price] > @PriceLimit
            )
        </Statement>
    </Command>
    <Properties>
        <PropertyList>
            <Catalog>ContosoDW</Catalog>
        </PropertyList>
    </Properties>
    <Parameters>
        <Parameter>
            <Name>PriceLimit</Name>
            <Value></Value>
        </Parameter>
    </Parameters>
</Execute>

The Value is mandatory in the Parameter node, as in the previous XMLA code. If the content of the Value node is empty, the parameter PriceLimit is passed as an empty string. Detecting such argument requires an IF statement, so that the VALUE function to convert the string into a number is executed only if the parameter is present. The variable MissingPriceLimit can be used to check whether the parameter is defined or not.

For example, this code uses 0 as a default value for PriceLimit:

EVALUATE
VAR MissingPriceLimit = ( @PriceLimit = "" )
VAR PriceLimit =
    IF (
        MissingPriceLimit,
        -- Use 0 as a default value is @PriceLimit is not specified
        0,
        VALUE ( @PriceLimit )
    )
RETURN
    CALCULATETABLE (
        'Product',
        'Product'[Unit Price] > PriceLimit
    )

The following version does not apply a filter to Product[Unit Price] if the PriceLimit parameter is missing (which means that it is passed as an empty string):

EVALUATE
VAR MissingPriceLimit = ( @PriceLimit = "" )
VAR PriceLimit =
    IF (
        MissingPriceLimit,
        -- Use 0 as a default value is @PriceLimit is not specified
        0,
        VALUE ( @PriceLimit )
    )
RETURN
    CALCULATETABLE (
        'Product',
        -- Consider all the values in Product[Unit Price] 
        -- if @PriceLimit parameter is missing
        MissingPriceLimit || 'Product'[Unit Price] > PriceLimit 
    )

If the parameter is used in a filter over a text column, the code can be shorter:

EVALUATE
VAR MissingColor = ( @Color = "" )
RETURN
    CALCULATETABLE (
        'Product',
        -- Consider all the values in Product[Unit Price] 
        -- if @Color parameter is missing
        MissingColor || 'Product'[Color] = @Color
    )

These examples should be helpful when I will not remember that we cannot use ISBLANK to check whether a parameter is missing in a DAX query!

CALCULATETABLE
Context transition

Evaluates a table expression in a context modified by filters.

CALCULATETABLE ( <Table> [, <Filter> [, <Filter> [, … ] ] ] )

IF

Checks whether a condition is met, and returns one value if TRUE, and another value if FALSE.

IF ( <LogicalTest>, <ResultIfTrue> [, <ResultIfFalse>] )

VALUE

Converts a text string that represents a number to a number.

VALUE ( <Text> )

ISBLANK

Checks whether a value is blank, and returns TRUE or FALSE.

ISBLANK ( <Value> )