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
Adri1
Frequent Visitor

Filter Count created, closed, closed on time, past due tickets on a date sumarry table by Location

Hi everyone,

 

I'm strugeling to came with a solution to build a report that shows trend of incidents and actions over time and behing able to filter this report by location. I'm able to get the results I want by creating a Summary Table and few measures but my problem is that I can't filter that Summary Table based on the Location Table. Here is the example.

 

I've 3 Tables linked together through Location ID:

  1. Action Table
  2. Location Table
  3. Incident Table

 

Since there are not necessarely Actions or Incidents for each months, I'm generating an additonal Table name Summary Table which will allows me to display the trend of the different caluclation over each period even for month where there are no incidents nor Actions. My issue is how to filter this Summary Table results by the Location.

 

2020-07-01_06-53-11.png

 

 Here are my measures used in Summary Table:

 

2020-07-01_07-39-52.png

 

Thanks in advance for your support
Adrien
 
 
 
2 ACCEPTED SOLUTIONS
parry2k
Super User
Super User

@Adri1 you are missing a date dimension table which is key to all this. As a best practice, add date dimension in your model and use it for and time intelligence calculations. Once the date dimension is added, mark it as a date table on table tools.

https://perytus.com/2020/05/22/create-a-basic-date-table-in-your-data-model-for-time-intelligence-ca...

 

Although you provided a lot of information, it will be easier if you throw some sample data or pbix with sample data and your expected output, it will help to provide a solution.

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop shop for Power BI related projects/training/consultancy.



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.

View solution in original post

v-alq-msft
Community Support
Community Support

Hi, @Adri1 

 

You may a date table as below. The pbix file is attached in the end.

 

Calendar = CALENDARAUTO()

 

 

Then you can create measures as below.

 

Start Period = MIN('Calendar'[Date])

End Period = MAX('Calendar'[Date])

Incident = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result = 
CALCULATE(
    DISTINCTCOUNT(Incident[Incident ID]),
    FILTER(
        ALLSELECTED(Incident),
        Incident[Created On]>=startperiod&&
        Incident[Created On]<=endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

Created Action = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result = 
CALCULATE(
    DISTINCTCOUNT('Action'[Action ID]),
    FILTER(
            ALLSELECTED('Action'),
            'Action'[Created On]>=startperiod&&
            'Action'[Created On]<=endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

Closed Action = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result =  
CALCULATE(
    DISTINCTCOUNT('Action'[Action ID]),
    FILTER(
        ALLSELECTED('Action'),
        'Action'[Closed On]>=startperiod&&
        'Action'[Closed On]<=endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

Closed On Time Action = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result = 
CALCULATE(
    DISTINCTCOUNT('Action'[Action ID]),
    FILTER(
        ALLSELECTED('Action'),
        'Action'[Closed On]>=startperiod&&
        'Action'[Closed On]<=endperiod&&
        'Action'[Due On]>endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

Past Due Action = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result = 
CALCULATE(
    DISTINCTCOUNT('Action'[Action ID]),
    FILTER(
        ALLSELECTED('Action'),
        'Action'[Created On]>=startperiod&&
        'Action'[Calc Closed On]>endperiod&&
        'Action'[Due On]<endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

 

 

Result:

g1.png

 

g2.png

 

Best Regards

Allan

 

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
v-alq-msft
Community Support
Community Support

Hi, @Adri1 

 

You may a date table as below. The pbix file is attached in the end.

 

Calendar = CALENDARAUTO()

 

 

Then you can create measures as below.

 

Start Period = MIN('Calendar'[Date])

End Period = MAX('Calendar'[Date])

Incident = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result = 
CALCULATE(
    DISTINCTCOUNT(Incident[Incident ID]),
    FILTER(
        ALLSELECTED(Incident),
        Incident[Created On]>=startperiod&&
        Incident[Created On]<=endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

Created Action = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result = 
CALCULATE(
    DISTINCTCOUNT('Action'[Action ID]),
    FILTER(
            ALLSELECTED('Action'),
            'Action'[Created On]>=startperiod&&
            'Action'[Created On]<=endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

Closed Action = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result =  
CALCULATE(
    DISTINCTCOUNT('Action'[Action ID]),
    FILTER(
        ALLSELECTED('Action'),
        'Action'[Closed On]>=startperiod&&
        'Action'[Closed On]<=endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

Closed On Time Action = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result = 
CALCULATE(
    DISTINCTCOUNT('Action'[Action ID]),
    FILTER(
        ALLSELECTED('Action'),
        'Action'[Closed On]>=startperiod&&
        'Action'[Closed On]<=endperiod&&
        'Action'[Due On]>endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

Past Due Action = 
var startperiod = [Start Period]
var endperiod = [End Period]
var result = 
CALCULATE(
    DISTINCTCOUNT('Action'[Action ID]),
    FILTER(
        ALLSELECTED('Action'),
        'Action'[Created On]>=startperiod&&
        'Action'[Calc Closed On]>endperiod&&
        'Action'[Due On]<endperiod
    )
)
return
IF(
    ISBLANK(result),
    0,
    result
)

 

 

Result:

g1.png

 

g2.png

 

Best Regards

Allan

 

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

@Adri1 , You need to create a date table and it will join with all dates in two tables. Only one relation will be active in each table.

The use userelation to activate.

Refer my blog on similar topics

https://community.powerbi.com/t5/Community-Blog/HR-Analytics-Active-Employee-Hire-and-Termination-tr...

parry2k
Super User
Super User

@Adri1 you are missing a date dimension table which is key to all this. As a best practice, add date dimension in your model and use it for and time intelligence calculations. Once the date dimension is added, mark it as a date table on table tools.

https://perytus.com/2020/05/22/create-a-basic-date-table-in-your-data-model-for-time-intelligence-ca...

 

Although you provided a lot of information, it will be easier if you throw some sample data or pbix with sample data and your expected output, it will help to provide a solution.

 

I would  Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos whoever helped to solve your problem. It is a token of appreciation!

Visit us at https://perytus.com, your one-stop shop for Power BI related projects/training/consultancy.



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.

Adri1
Frequent Visitor

Thank you it works now

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.