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

The ultimate Microsoft Fabric, Power BI, Azure AI & SQL learning event! Join us in Las Vegas from March 26-28, 2024. Use code MSCUST for a $100 discount. Register Now

Reply
MalyMajo
Frequent Visitor

Mapping of phases to dates

Hello,

 

I have a table of actual hours submitted to system and I would like to map the phases according to a custom table.

 

Example of actual hours table:

Resource Name

DateHours
Resource15/1/20221
Resource16/30/20225
Resource26/30/20224

 

Example of phases table:

StartEndPhase
5/1/20226/15/2022Phase1
6/16/20228/31/2022Phase2

 

What is the most efficient approach to map these tables so in final I would see which hours belong under which phase?

Should I merge somehow the phases table to calendar table in power query? Or using DAX? 

Please note that the table with actuals has 10,000+ rows, above is just a simplified example.

 

Thanks,

Majo

1 ACCEPTED SOLUTION
DataInsights
Super User
Super User

@MalyMajo,

 

Here's a DAX solution. No relationship exists between ActualHours and Phases.

 

Calculated column in ActualHours:

 

Phase = 
VAR vDate = ActualHours[Date]
VAR vTable =
    FILTER ( Phases, vDate >= Phases[Start] && vDate <= Phases[End] )
VAR vResult =
    MAXX ( vTable, Phases[Phase] )
RETURN
    vResult

 

DataInsights_0-1657815764263.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




View solution in original post

2 REPLIES 2
DataInsights
Super User
Super User

@MalyMajo,

 

Here's a DAX solution. No relationship exists between ActualHours and Phases.

 

Calculated column in ActualHours:

 

Phase = 
VAR vDate = ActualHours[Date]
VAR vTable =
    FILTER ( Phases, vDate >= Phases[Start] && vDate <= Phases[End] )
VAR vResult =
    MAXX ( vTable, Phases[Phase] )
RETURN
    vResult

 

DataInsights_0-1657815764263.png

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




Hello,

 

as per my understanding, calculated columns are less effective than measures.

But in this case it is not possible because result is a string, or is it?

Thanks,
Majo
--------------
EDIT: Never mind, I got it quickly. 🙂

Actuals:=
VAR SumActuals = SUM(Actuals[Hours])
VAR vDate = MAX(Actuals[Date])
VAR vTable= FILTER ( Phases, vDate >= Phases[Start] && vDate <= Phases[End] )
VAR vResult = MAXX ( vTable, Phases[Phase] )
RETURN
CALCULATE(SumActuals,Phases[Phase]=vResult)

Helpful resources

Announcements
Fabric Community Conference

Microsoft Fabric Community Conference

Join us at our first-ever Microsoft Fabric Community Conference, March 26-28, 2024 in Las Vegas with 100+ sessions by community experts and Microsoft engineering.

February 2024 Update Carousel

Power BI Monthly Update - February 2024

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

Fabric Career Hub

Microsoft Fabric Career Hub

Explore career paths and learn resources in Fabric.

Fabric Partner Community

Microsoft Fabric Partner Community

Engage with the Fabric engineering team, hear of product updates, business opportunities, and resources in the Fabric Partner Community.

Top Solution Authors