Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
AndrewTobin
Frequent Visitor

Refactoring a snowflake dimension that combines parent branches of an office

Hey folks,

 

I've got a bit of a problem that I've got a solution for, but I don't think it's an optimum solution, and I'm not sure of the right terms to search for a better solution, so I am hoping you can help.

 

Basically, we have a structure where Orders get split to different offices, and we have split the orders themselves into a Dimension Sending Location and a Dimension Receiving Location.

 

We then have a Dimension Parent Branch that then is linked to each of these Location Dimension's so we have a single filter that can give us: all Fact Sending Orders sent by Dimension Sending Location X and received by any Location, and all Fact Receiving Orders received by Location X and sent by any Location.

 

This seems to me to be a very end visual concern to be placing in the model, and it means if I have any other Fact tables that have both Locations in them, and I join to both, then it will get filtered only to the same Dimension Parent Branch for sending and receiving.

 

This also means that we are storing the parent branch in both the Dimension Locations and the Dimension Parent Branch as they want to be able to get those parent branches for reporting out where orders have been sent from and received by, meaning a duplication of data, and it feels problematic.

 

I feel like I should have a Dimenion Sending Parent Branch and a Dimension Receiving Parent Branch but the analysts are pushing for the single filter for both Locations.

 

Is there any good way around this? Having a third Filter Parent Branch for this?  I can't think of a way to get a Slider and a single Parameter to filter two Dimensions if I split the Dimension Parent Branch into two.

 

Edit to add a simplified model - you can see where I have a problem with the joined Parent and the single active relationship on the new Fact being added.

AndrewTobin_0-1659261601509.png

 

 

 

1 ACCEPTED SOLUTION
speedramps
Super User
Super User

Hi AndrewTobin

The best practice for this type of common problem is to use a technique called  “role playing relationships”.

 

Create one combined Dimension table called DimLocation with

  • LocationID
  • Branch name
  • Branch city
  • Parent name

 

The crate one combined  Facts table calls Facts with

  • SendingLocationID
  • ReceivingLocationID
  • OrderQty
  • PhoneCalls

 

Then add two inactive relationships:-

  • DimLocation[LocationID] 1:M Facts[SendingLocationID]
  • DimLocation[LocationID] 1:M Facts[ReceivingLocationID]

 

Then add 4 measures:-

Sent qty =

CALCULATE(

    SUM(Facts[OrderTty]),

    USERELATIONSHIP(DimLocation[LocationID], Facts[SendingLocationID]]))

Sent calls =

CALCULATE(

    SUM(Facts[PhoneCalsl]),

    USERELATIONSHIP(DimLocation[LocationID], Facts[SendingLocationID]]))

Received qty =

CALCULATE(

    SUM(Facts[OrderTty]),

    USERELATIONSHIP(DimLocation[LocationID], Facts[ReceivingLocationID]]))

Received calls =

CALCULATE(

    SUM(Facts[PhoneCalsl]),

    USERELATIONSHIP(DimLocation[LocationID], Facts[ReceivingLocationID]]))

 

 

Then hide all the Fact columns to force the user to use the role playing measures.

To create a sent report

  • Drag a table visual to a blank report canvas and drag
  • Parent name, Branch name, Sent qty, Sent calls

To create a receicing report

  • Drag a table visual to a blank report canvas and drag
  • Parent name, Branch name, Received qty, Received calls

 

Sorry this example uses dates and not locations, but the "role play" principle and logic is exactly the same.
Click here to download an example 

Thanks for reaching out for help.

I put in a lot of effort to help you, now please quickly help me by giving kudos.

Remeber we are unpaid volunteers and here to coach you with Power BI and DAX skills and techniques, not do the users job for them. So please click the thumbs up and accept as solution button. 

If you give someone a fish then you only give them one meal, but if you teach them how to fish then they can feed themselves and teach others for a lifetime.  I prefer to teach members on this forum techniques rather give full solutions and do their job. You can then adapt the technique for your solution, learn some DAX skills for next time and soon become a Power BI Super User like me. 

 

One question per ticket please. If you need to extend your request then please raise a new ticket.

You will get a quicker response and each volunteer solver will get the kudos they deserve. Thank you ! 

 



 

 

View solution in original post

1 REPLY 1
speedramps
Super User
Super User

Hi AndrewTobin

The best practice for this type of common problem is to use a technique called  “role playing relationships”.

 

Create one combined Dimension table called DimLocation with

  • LocationID
  • Branch name
  • Branch city
  • Parent name

 

The crate one combined  Facts table calls Facts with

  • SendingLocationID
  • ReceivingLocationID
  • OrderQty
  • PhoneCalls

 

Then add two inactive relationships:-

  • DimLocation[LocationID] 1:M Facts[SendingLocationID]
  • DimLocation[LocationID] 1:M Facts[ReceivingLocationID]

 

Then add 4 measures:-

Sent qty =

CALCULATE(

    SUM(Facts[OrderTty]),

    USERELATIONSHIP(DimLocation[LocationID], Facts[SendingLocationID]]))

Sent calls =

CALCULATE(

    SUM(Facts[PhoneCalsl]),

    USERELATIONSHIP(DimLocation[LocationID], Facts[SendingLocationID]]))

Received qty =

CALCULATE(

    SUM(Facts[OrderTty]),

    USERELATIONSHIP(DimLocation[LocationID], Facts[ReceivingLocationID]]))

Received calls =

CALCULATE(

    SUM(Facts[PhoneCalsl]),

    USERELATIONSHIP(DimLocation[LocationID], Facts[ReceivingLocationID]]))

 

 

Then hide all the Fact columns to force the user to use the role playing measures.

To create a sent report

  • Drag a table visual to a blank report canvas and drag
  • Parent name, Branch name, Sent qty, Sent calls

To create a receicing report

  • Drag a table visual to a blank report canvas and drag
  • Parent name, Branch name, Received qty, Received calls

 

Sorry this example uses dates and not locations, but the "role play" principle and logic is exactly the same.
Click here to download an example 

Thanks for reaching out for help.

I put in a lot of effort to help you, now please quickly help me by giving kudos.

Remeber we are unpaid volunteers and here to coach you with Power BI and DAX skills and techniques, not do the users job for them. So please click the thumbs up and accept as solution button. 

If you give someone a fish then you only give them one meal, but if you teach them how to fish then they can feed themselves and teach others for a lifetime.  I prefer to teach members on this forum techniques rather give full solutions and do their job. You can then adapt the technique for your solution, learn some DAX skills for next time and soon become a Power BI Super User like me. 

 

One question per ticket please. If you need to extend your request then please raise a new ticket.

You will get a quicker response and each volunteer solver will get the kudos they deserve. Thank you ! 

 



 

 

Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.