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
FlowViz
Helper III
Helper III

Help with query across tables

Hi Guys,

 

I have a Jira dataset structured like so (edit: table name - Cycle Time 2):

Screenshot 2022-03-21 at 19.44.56.png

 

And I also have a date table:

Screenshot 2022-03-21 at 19.34.06.png

 

I want to be able to count:

1) How many items are In Progress (i.e. not in a status of 'Done' (in the NewStatus column) on a given date

2) For each WorkItemID, the age (i.e how long since it first went 'In Progress') of it on a given date.

 

For example, on the 19th March - there are 4 items 'In Progress' - TP-5, TP-6, TP-7 and TP-9

TP-5, TP-6, TP-7 have an age of 2, TP-9 would have an age of 0

 

I'm really struggling with how it could be done - .PBIX is here - can anyone help?

10 REPLIES 10
FlowViz
Helper III
Helper III

Thank you.

That's still not quite what I'm after, I have refreshed the data (and fixed some DQ issues) and re-uploaded here.

 

In the Excel template (not my own) I use, I input the following data:

 

Screenshot 2022-03-31 at 14.35.49.png

And seeing these results (this is the end result I'm trying to get to):

Screenshot 2022-03-31 at 14.31.15.png

 

v-angzheng-msft
Community Support
Community Support

Hi, @FlowViz 

Create the following measures:

 

_selectedDate = 
var _date=SELECTEDVALUE('Dates'[Date])
return
Date(
    year(_date),MONTH(_date),DAY(_date))
_isIn = 
var _selectedDate=[_selectedDate]
var _currentStatus=SELECTEDVALUE('CycleTime (2)'[NewStatus])

var _ChangeDate=SELECTEDVALUE('CycleTime (2)'[ChangedDate])
var _dateStart=DATE(YEAR(_ChangeDate),MONTH(_ChangeDate),DAY(_ChangeDate))
var _CompletedDate=SELECTEDVALUE('CycleTime (2)'[CompletedDate])
var _dateEnd=DATE(YEAR(_CompletedDate),MONTH(_CompletedDate),DAY(_CompletedDate))

var _if=
IF(
    _currentStatus<>"Done"&&
    AND(_selectedDate>=_dateStart,_selectedDate<=_dateEnd),1,0
    
)
return _if
_count = SUMX('CycleTime (2)',CALCULATE([_isIn]))
_age = 
IF([_isIn]=0,BLANK(),DATEDIFF(SELECTEDVALUE('CycleTime (2)'[ChangedDate]),[_selectedDate],DAY))

 

Result:

vangzhengmsft_0-1648186601819.png

Please refer to the attachment below for details.

Hope this helps.

 

 

Best Regards,
Community Support Team _ Zeon Zheng


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

Thank you!

 

One final question - if there have been no changes to items then there will be no updates to the history, however they will still be 'In Progress'. So if my current chart now looks like this:

Screenshot 2022-03-25 at 17.32.12.png

It should stay at the value of 3 for the 22/23/24/25 March.

Is there anyway to do this?

Hi, @FlowViz 

 

Try to create another measure like this:

_sum = SUMX(FILTER(ALLSELECTED('CycleTime (2)'),'CycleTime (2)'[ChangedDate]<=MAX('CycleTime (2)'[ChangedDate])),[_count])

Result:

vangzhengmsft_0-1648527638960.png

Please refer to the attachment below for details.

Hope this helps.

 

 

Best Regards,
Community Support Team _ Zeon Zheng


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

v-angzheng-msft
Community Support
Community Support

Hi, @FlowViz 

For example, on the 19th March - there are 4 items 'In Progress' - TP-5, TP-6, TP-7 and TP-9

TP-5, TP-6, TP-7 have an age of 2, TP-9 would have an age of 0

I can't seem to understand the example from your sample data properly.
Can you explain in more detail how the above example works

vangzhengmsft_0-1648089913194.png

 

 

Best Regards,
Community Support Team _ Zeon Zheng


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

Sure thing:

Screenshot 2022-03-24 at 17.04.23.png 

On 17th March, the In Progress count should be 3 (TP-5, TP-6, TP-7) all of which should have an age of 0 (as they all went 'InProgress' that date).

On 18th March, the In Progress count should be 2 (TP-5, TP-6, - TP-7 is finished) both of which should have an age of 1 (as they all went 'InProgress' the date before).

On 19th March, the In Progress count should be 3 (TP-5, TP-6, TP-9) with an age of 2 for both TP-5 and TP-6, and an age of 0 for TP-9 (as it went 'InProgress' that date).

On 20th March, the In Progress count should be 1 (TP-9 - TP-5 and TP-6 are now finished) with an age of 1 (as it went 'InProgress' the date before).

 

I'm trying to create these two charts:

Daily%20WIPDaily%20WIP%20and%20Work%20Item%20Age

parry2k
Super User
Super User

@FlowViz there seems to be a disconnect between the file you shared and the screenshot, there is no old status and new status column. Can you please revisit your post and make sure pbix file has the relevant details. 



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

This should now be updated in the file, apologies again...

parry2k
Super User
Super User

@FlowViz you have many tables in the report, what is the workitem table with status?



Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!

Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo

If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤


Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.

Oh yes sorry I should have said that shouldn't i (doh) 

 

Cycle Time (2) is the table...

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.