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

Power BI is turning 10! Let’s celebrate together with dataviz contests, interactive sessions, and giveaways. Register now.

Reply
hartlbb
New Member

Flatten Table with Dax

Hi there,

 

I have a table (current below), which has a common ID with phases associated with it.  I am trying to display the time between phase (e.g. for ID 1 Phase A would be 1 hour of time, phase B would be 1 minute, etc).  I was thinking of flattening the table (see flatten table format below).  Is this possible in DAX?

 

Current Table Format:

IDPhaseStartEnd
1A12:00 AM1:00 AM
1B1:00 AM1:01 AM
1C1:01 AM1:02 AM
2A12:00 AM1:00 AM
2B1:00 AM1:01 AM
2C1:01 AM1:02 AM

 

Flatten Table Format:

IDPhaseAPhaseAStartPhaseAEndPhaseBPhaseBStartPhaseBEndPhaseCPhaseCStartPhaseCEnd
1 ACCEPTED SOLUTION

Hi, @hartlbb 

 

Please check the following methods.

Table2 = Summarize('Table', 'Table'[ID],
"Phase A Start", Minx(filter('Table', 'Table'[Phase] ="A" ), [Start]),
"Phase A END", Maxx(filter('Table', 'Table'[Phase] ="A" ), [End]),
"Phase B Start", Minx(filter('Table', 'Table'[Phase] ="B" ), [Start]),
"Phase B END", Maxx(filter('Table', 'Table'[Phase] ="B" ), [End]),
"Phase C Start", Minx(filter('Table', 'Table'[Phase] ="C" ), [Start]),
"Phase C END", Maxx(filter('Table', 'Table'[Phase] ="C" ), [End]),
"AvailabilityDuration",DATEDIFF(Minx(FILTER('Table',[Phase]="A"),[Start]),Minx(FILTER('Table',[Phase]="B"),[Start]),SECOND))

vzhangti_0-1659600460100.png

Is this the result you expect? If not, please provide more details.

 

Best Regards,

Community Support Team _Charlotte

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

3 REPLIES 3
hartlbb
New Member

Thank you, worked perfectly.  I am not trying to calc the phase times, troulbe on this statement:

 

"AvailabilityDuration" = DATEDIFF(Minx(FILTER('Logs_Perf','Logs_Perf'[phaseName]="Availability"),'Logs_Perf'[startTime]),Minx(FILTER('Logs_Perf','Logs_Perf'[phaseName]="Ingestion"),'Logs_Perf'[startTime]),SECOND))

Hi, @hartlbb 

 

Please check the following methods.

Table2 = Summarize('Table', 'Table'[ID],
"Phase A Start", Minx(filter('Table', 'Table'[Phase] ="A" ), [Start]),
"Phase A END", Maxx(filter('Table', 'Table'[Phase] ="A" ), [End]),
"Phase B Start", Minx(filter('Table', 'Table'[Phase] ="B" ), [Start]),
"Phase B END", Maxx(filter('Table', 'Table'[Phase] ="B" ), [End]),
"Phase C Start", Minx(filter('Table', 'Table'[Phase] ="C" ), [Start]),
"Phase C END", Maxx(filter('Table', 'Table'[Phase] ="C" ), [End]),
"AvailabilityDuration",DATEDIFF(Minx(FILTER('Table',[Phase]="A"),[Start]),Minx(FILTER('Table',[Phase]="B"),[Start]),SECOND))

vzhangti_0-1659600460100.png

Is this the result you expect? If not, please provide more details.

 

Best Regards,

Community Support Team _Charlotte

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

amitchandak
Super User
Super User

@hartlbb , a new table


Summarize(Table, Table[ID],
"Phase A Start", Minx(filter(Table, Table[Phase] ="A" ), [Start Date]),
"Phase A END", Maxx(filter(Table, Table[Phase] ="A" ), [END Date]),
"Phase B Start", Minx(filter(Table, Table[Phase] ="A" ), [Start Date]),
"Phase B END", Maxx(filter(Table, Table[Phase] ="A" ), [END Date]),
"Phase C Start", Minx(filter(Table, Table[Phase] ="A" ), [Start Date]),
"Phase C END", Maxx(filter(Table, Table[Phase] ="A" ), [END Date]))

 

Or use Phase on Matrix column, Only Visual solution

Full Power BI Video 20 Hours YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

Helpful resources

Announcements
June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

Check out the June 2025 Power BI update to learn about new features.

June 2025 community update carousel

Fabric Community Update - June 2025

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