Table of contents
TOC
Collapse the table of content
Expand the table of content

SUMMARIZECOLUMNS Function (DAX)

Owen Duncan|Last Updated: 10/5/2018
|
1 Contributor

Returns a summary table over a set of groups.

Syntax

SUMMARIZECOLUMNS( <groupBy_columnName> [, < groupBy_columnName >]…, [<filterTable>]…[, <name>, <expression>]…)  

Parameters

TermDefinition
groupBy_columnNameA fully qualified column reference (Table[Column]) to a base table for which the distinct values are included in the returned table. Each groupBy_columnName column is cross-joined (different tables) or auto-existed (same table) with the subsequent specified columns.
filterTableA table expression which is added to the filter context of all columns specified as groupBy_columnName arguments. The values present in the filter table are used to filter before cross-join/auto-exist is performed.
nameA string representing the column name to use for the subsequent expression specified.
expressionAny DAX expression that returns a single value (not a table).

Return Value

A table which includes combinations of values from the supplied columns, based on the grouping specified. Only rows for which at least one of the supplied expressions return a non-blank value are included in the table returned. If all expressions evaluate to BLANK/NULL for a row, that row is not included in the table returned.

Remarks

SUMMARIZECOLUMNS does not guarantee any sort order for the results.

A column cannot be specified more than once in the groupBy_columnName parameter. For example, the following formulas are invalid.

SUMMARIZECOLUMNS( Sales[StoreId], Sales[StoreId] )

Filter context

Consider the following query:

SUMMARIZECOLUMNS ( 'Sales Territory'[Category], FILTER('Customer', 'Customer' [First Name] = “Alicia”) )

In this query, without a measure the groupBy columns do not contain any columns from the Filter expression (i.e. from Customer table). The filter is not applied to the groupBy columns. The Sales Territory and the Customer table may be indirectly related through the Reseller sales fact table. Since they're not directly related, the filter expression is a no-op and the groupBy columns are not impacted.

However, with this query:

SUMMARIZECOLUMNS ( 'Sales Territory'[Category], 'Customer' [Education], FILTER('Customer', 'Customer'[First Name] = “Alicia”) )

The groupBy columns contain a column which is impacted by the filter and that filter is applied to the groupBy results.

Options

IGNORE

The IGNORE() syntax can be used to modify the behavior of the SUMMARIZECOLUMNS function by omitting specific expressions from the BLANK/NULL evaluation. Rows for which all expressions not using IGNORE return BLANK/NULL will be excluded independent of whether the expressions which do use IGNORE evaluate to BLANK/NULL or not.

Syntax

IGNORE(<expression>)

With SUMMARIZECOLUMNS

SUMMARIZECOLUMNS(<groupBy_columnName>[, < groupBy_columnName >]…, [<filterTable>]…[, <name>, IGNORE(…)]…)

Parameters

TermDefinition
expressionAny DAX expression that returns a single value (not a table).

Return value

This function does not return a value.

Remarks

IGNORE can be used as an expression argument to SUMMARIZECOLUMNS.

Example

SUMMARIZECOLUMNS( Sales[CustomerId], "Total Qty", IGNORE( SUM( Sales[Qty] ) ), “BlankIfTotalQtyIsNot3”, IF( SUM( Sales[Qty] )=3, 3 ) )

This rolls up the Sales[CustomerId] column, creating a subtotal for all customers in the given grouping. Without IGNORE, the result is:

CustomerIdTotalQtyBlankIfTotalQtyIsNot3
A5
B33
C33

With IGNORE

CustomerIdTotalQtyBlankIfTotalQtyIsNot3
B33
C33

All expression ignored

SUMMARIZECOLUMNS( Sales[CustomerId], "Blank", IGNORE( Blank() ), “BlankIfTotalQtyIsNot5”, IGNORE( IF( SUM( Sales[Qty] )=5, 5 ) ) )

Even though both expressions return blank for some rows, they're included since there are no non-ignored expressions which return blank.

CustomerIdTotalQtyBlankIfTotalQtyIsNot3
A5
B
C

ROLLUPADDISSUBTOTAL()

The addition of the ROLLUPADDISSUBTOTAL() syntax modifies the behavior of the SUMMARIZECOUMNS function by adding roll-up/subtotal rows to the result based on the groupBy_columnName columns.

Syntax

ROLLUPADDISSUBTOTAL ( <groupBy_columnName>, <isSubtotal_columnName>[, <groupBy_columnName >, <isSubtotal_columnName>…] )

Parameters

TermDefinition
groupBy_columnNameThe qualified name of an existing column to be used to create summary groups based on the values found in it. This parameter cannot be an expression.
isSubtotal_columnNameThe name of the Boolean column to be added to the result, indicating whether or not a row is a subtotal over the groupBy column (or columns when used with ROLLUPGROUP). This value is calculated using the ISSUBTOTAL function.

Return Value

The function does not return a value. It only specifies the set of columns to be subtotaled.

Example

Single subtotal

SUMMARIZECOUMNS (Regions[State], ROLLUPADDISSUBTOTAL ( Sales[CustomerId], “IsCustomerSubtotal” ), Sales[Date], "Total Qty", SUM( Sales[Qty] ))

Result

CustomerIDIsCustomerSubtotalStateTotal Qty
AFALSEWA5
BFALSEWA3
CFALSEOR3
TRUEWA8
TRUEOR3

Multiple subtotals

SUMMARIZECOUMNS ( Regions[State], ROLLUPADDISSUBTOTAL ( Sales[CustomerId], "IsCustomerSubtotal" ), ROLLUPADDISSUBTOTAL ( Sales[Date], "IsDateSubtotal"), "Total Qty", SUM( Sales[Qty] ) )

Sales is grouped by state, by customer, by date, with subtotals for 1. Sales by state, by date 2. Sales by State, by Customer 3. Rolled up on both customer and date leading to sales by state.

Result

CustomerIDIsCustomerSubtotalStateTotal QtyDateIsDateSubtotal
AFALSEWA57/10/2014
BFALSEWA17/10/2014
BFALSEWA27/11/2014
CFALSEOR27/10/2014
CFALSEOR17/11/2014
TRUEWA67/10/2014
TRUEWA27/11/2014
TRUEOR27/10/2014
TRUEOR17/11/2014
AFALSEWA5TRUE
BFALSEWA3TRUE
CFALSEOR3TRUE
TRUEWA8TRUE
TRUEOR3TRUE

ROLLUPGROUP()

Like with the SUMMARIZE function, ROLLUPGROUP can be used together with ROLLUPADDISSUBTOTAL to specify which summary groups/granularities (subtotals) to include (reducing the number of subtotal rows returned).

Syntax

ROLLUPGROUP(<groupBy_columnName>, <groupBy_columnName>)

With ROLLUPADDISSUBTOTAL

ROLLUPADDISSUBTOTAL( ROLLUPGROUP(…), isSubtotal_columnName[, <groupBy_columnName>…] )

Parameters

TermDefinition
groupBy_columnNameThe qualified name of an existing column to be used to create summary groups based on the values found in it. The set of group by columns supplied to ROLLUPGROUP function will define the granularity to return subtotal rows for (same behavior as when ROLLUP and ROLLUPGROUP are used with the SUMMARIZE function). This parameter cannot be an expression.

Return Value

The function does not return a value. It marks a set of columns to be grouped during subtotaling by ROLLUPADDISSUBTOTAL.

Remarks

ROLLUPGROUP can only be used as an groupBy_columnName argument to ROLLUPADDISSUBTOTAL or the SUMMARIZE function.

Example

Multiple subtotals

SUMMARIZECOLUMNS( ROLLUPADDISSUBTOTAL( Sales[CustomerId], "IsCustomerSubtotal" ), ROLLUPADDISSUBTOTAL(ROLLUPGROUP(Regions[City], Regions[State]), “IsCityStateSubtotal”),"Total Qty", SUM( Sales[Qty] ) )

Still grouped by City and State, but rolled together when reporting a subtotal.

Result

StateCustomerIdIsCustomerSubtotalTotal QtyCityIsCityStateSubtotal
WAAFALSE2BellevueFALSE
WABFALSE2BellevueFALSE
WAAFALSE3RedmondFALSE
WABFALSE1RedmondFALSE
ORCFALSE3PortlandFALSE
WATRUE4BellevueFALSE
WATRUE4RedmondFALSE
ORTRUE3PortlandFALSE
AFALSE5FALSE
BFALSE3TRUE
CFALSE3TRUE
TRUE11TRUE

See Also

SUMMARIZE Function (DAX)

© 2018 Microsoft