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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
AndyB
Helper I
Helper I

Fill Future Dates in Date Dimension Table and then filter using 3rd Dimension Table

Hello,

 

I have a problem where I am trying to fill the most recent values from a Fact Table (Fact_BackupStorage_Data) to all dates in my Date table (DIM_Date), and then filter out a number of rows when a Host reaches end of life in a 3rd table (DIM_BackupStorage_Nodes).

 

Any help would be appreciated as I am really struggling with this one! Please let me know if I have explained poorly.

 

My FACT_BackupStorage_Data table looks like the below. This table has no future data, so the values end at 18/10/2021.

DateHostCapacity
16/10/2021Host1100GB
16/10/2021Host2900GB
17/10/2021Host1100GB
17/10/2021Host2900GB
18/10/2021Host1100GB
18/10/2021Host2900GB

 

The DIM_BackupStorage_Nodes table looks like the below.

 

HostEOL Date
Host120/10/2021
Host201/01/2022

 

What I need to achieve is to fill the capacity forward, with the last non blank value,so 19/10/2021 also shows 1000GB.

Then when the EOL date is met on the DIM_BackupStorage_Nodes table, filter out all hosts from the filled value calculation, like the below, where Host1's 100GB is removed from the calculation when the EOL date is reached.

 

DateCapacity GB
16/10/20211000GB
17/10/20211000GB
18/10/20211000GB
19/10/2021 (Future Date)1000GB
20/10/2021 (EOL Date for Host1)900GB

 

The relationships are setup like the below - I can't link the DIM_Date, Date field onto EndOfLifeDate because it would introduce ambiguity as an indirect relationship exists.

 

RelationshipsRelationships

 

 

 

1 ACCEPTED SOLUTION

Hi @AndyB 

I have a test in your sample. Please try this code.

M_Capacity = 
VAR _LASTDATE = CALCULATE(MAX(FACT_BackupStorage_Data[Date]),ALL(FACT_BackupStorage_Data))
VAR _LASTCAPACITY = CALCULATE(SUM(FACT_BackupStorage_Data[Capacity]),FILTER(ALL(FACT_BackupStorage_Data),FACT_BackupStorage_Data[Date] = _LASTDATE))
VAR _FirstEOLDate = MIN(DIM_BackupStorage_Nodes[EOL Date])
VAR _FirstEOLHOST = CALCULATE(MAX(DIM_BackupStorage_Nodes[Host]),FILTER(ALL(DIM_BackupStorage_Nodes),DIM_BackupStorage_Nodes[EOL Date] = _FirstEOLDate))
VAR _CAPACITYAFTEREOL = CALCULATE(SUM(FACT_BackupStorage_Data[Capacity]),FILTER(ALL(FACT_BackupStorage_Data),AND(FACT_BackupStorage_Data[Date] = _LASTDATE,FACT_BackupStorage_Data[Host]<>_FirstEOLHOST)))
VAR _IF = IF(MAX(DIM_Date[Date])<=_LASTDATE,SUM(FACT_BackupStorage_Data[Capacity]),IF(MAX(DIM_Date[Date])<_FirstEOLDate,_LASTCAPACITY,_CAPACITYAFTEREOL))
VAR _RESULT = IF(_IF = BLANK(),BLANK(),_IF&""&"GB")
RETURN
_RESULT

Result is as below.

1.png

Best Regards,
Rico Zhou

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

View solution in original post

4 REPLIES 4
amitchandak
Super User
Super User

@AndyB , You should not join two dimensions. so Date should not join with DIM_BackupStorage_Nodes .

 

You can use the date range from slicer as filter in the measures you need to filter date from DIM_BackupStorage_Nodes 

 

measures  =

=
var _max = maxx(allselected('Date'), 'Date'[Date])
var _min = maxx(allselected('Date'), 'Date'[Date])
return

calculate (countrows(FACT_BackupStorage_Data ), filter( DIM_BackupStorage_Nodes , DIM_BackupStorage_Nodes [EOL] >=_min  && DIM_BackupStorage_Nodes [EOL] <= _max))

 

If needed, use all(Date) remove the filter from fact(that should be active), or use crossfilter for that.

 

You can keep both joins inactive and try userelationship as per need

 

Hi @amitchandak 

 

Thanks so much for taking the time to reply.

 

I've attempted using the measure you applied above, but unfortunately was not successful. The measure shows only blanks when I create a table with the Date from the DIM_Date table and your measure.

 

I think I understand the concept of your measure, it's taking all selected dates from date dimension, giving me the value in the first stage of the calculate step, and then filtering it by dates when they are greater than the earliest EOL date.

 

I'm confused as to why it's not showing any values, as to me that logic makes sense. I've attached a screenshot below, and a scrubbed PBIX file, if you could point me to where I've gone wrong, it would be much appreciated! I have used CrossFilter / UseRelationship before, but not sure where I would apply them here.

 

Pbix Link (WeTransfer) 

 

pbiforums.png

 

 

Hi @AndyB 

I have a test in your sample. Please try this code.

M_Capacity = 
VAR _LASTDATE = CALCULATE(MAX(FACT_BackupStorage_Data[Date]),ALL(FACT_BackupStorage_Data))
VAR _LASTCAPACITY = CALCULATE(SUM(FACT_BackupStorage_Data[Capacity]),FILTER(ALL(FACT_BackupStorage_Data),FACT_BackupStorage_Data[Date] = _LASTDATE))
VAR _FirstEOLDate = MIN(DIM_BackupStorage_Nodes[EOL Date])
VAR _FirstEOLHOST = CALCULATE(MAX(DIM_BackupStorage_Nodes[Host]),FILTER(ALL(DIM_BackupStorage_Nodes),DIM_BackupStorage_Nodes[EOL Date] = _FirstEOLDate))
VAR _CAPACITYAFTEREOL = CALCULATE(SUM(FACT_BackupStorage_Data[Capacity]),FILTER(ALL(FACT_BackupStorage_Data),AND(FACT_BackupStorage_Data[Date] = _LASTDATE,FACT_BackupStorage_Data[Host]<>_FirstEOLHOST)))
VAR _IF = IF(MAX(DIM_Date[Date])<=_LASTDATE,SUM(FACT_BackupStorage_Data[Capacity]),IF(MAX(DIM_Date[Date])<_FirstEOLDate,_LASTCAPACITY,_CAPACITYAFTEREOL))
VAR _RESULT = IF(_IF = BLANK(),BLANK(),_IF&""&"GB")
RETURN
_RESULT

Result is as below.

1.png

Best Regards,
Rico Zhou

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

Hi @v-rzhou-msft 

 

Thank you so much! That's working perfectly after having applied it to my real dataset also.

 

Really appreciate the help!

 

Kind regards

Andy

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

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.