cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
CrassJoin
Advocate I
Advocate I

SSAS Tabular - Default Detail Rows Expression

For a SSAS 2017 tabular model surfaced via pivot tables, a handy (vital) feature is the ability to drill through to a sensible selection of detail rows via double click on a measure (just like in the old school Excel pivot tables that your finance department can't part with). The content of the drillthough is determined by the table property [Default Detail Rows Expression]. The example Microsoft provides here is great insofar as it goes.

SELECTCOLUMNS(
    'Internet Sales',
    "Customer First Name", RELATED( Customer[Last Name]),
    "Customer Last Name", RELATED( Customer[First Name]),
    "Order Date", 'Internet Sales'[Order Date],
    "Internet Total Sales", [Internet Total Sales]
)

My problem is that I have a calendar table with an active relationship with my fact table (let's call this fact column end_date_sk) and an inactive relationship with the same table (let's call this fact column start_date_sk). If I want to return calendar columns from both the inactive and active relationships, what do I do? RELATED() only seems to work for the active relationship.

3 REPLIES 3
Anonymous
Not applicable

You have to change the relationship via a combination of CALCULATE and USERELATIONSHIP. But be careful where you do it. RELATED must work AFTER the relationship has been activated, not before.

Best
Darek

Thanks @Anonymous 

Can you link to an example of this? I tried USERELATIONSHIP with no joy.

Anonymous
Not applicable

Using RELATED(TABLE) is tricky with inactive relationships. Here's the code you're after.

 

New Table = 
SELECTCOLUMNS(
    'Fact',
    "Value For Column 1", RELATED( Dim[Value] ),
    "Value For Column 2",
        CALCULATE (
            CALCULATE (
                VALUES ( Dim[Value] ),
                'Fact'
            ),
            USERELATIONSHIP ( Dim[Column], 'Fact'[Column 2] ),
            ALL ( Dim )
        )
)

Assumptions:

  1. Fact is the fact table with 2 columns, Column 1 and Column 2. Both join on Column to Dim.
  2. Dim is a dimension table with Column and Value.
  3. The above retrieves the Value for Column 1 and Column 2 for each of of the rows in Fact.

If you want to know why so, please go to this article and read.

 

Best

Darek

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

Microsoft Business Applications Summit sessions

On-demand access to all the great content presented by the product teams and community members! #MSBizAppsSummit #CommunityRocks

Get Ready for Power BI Dev Camp

Power BI Dev Camp - June 24th

Mark your calendars and join us for our next Power BI Dev Camp!

Top Solution Authors
Top Kudoed Authors