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
Magic_Analyst
New Member

DAX Help - Count of Ticket IDs

Hi Community, 

 

I am facing an issue with a DAX command in Power BI. My current approach is to set up a new table in order to achieve my desired result. If there is any way of doing the same result by the help of a measure for example, I would be happy to implement it as well. 

 

My data is about certain ticket IDs depicted by a unique string. Further, I have a month, in which the ticket has been opened as well as a month, in which the ticket has been closed. 

Magic_Analyst_0-1699375001223.png

 

I want to show a bar chart with all relevant months on the x-axis and the number of tickets on the y-axis:

 

Magic_Analyst_1-1699375089107.png

 

The way how the ticket count should be calculated is the following: If a ticket is open e.g. from January 2023 to March 2023, the bar chart shows one ticket for January, February and March. Only when the ticket is closed, it should not be displayed in the following months any more (so from April 2023 to October 2023 (today) it should not display a ticket in the bar chart). 

My current table is set up with the following DAX code resulting in the following table: 

Magic_Analyst_2-1699375253268.png


Now I would like to include the Ticket ID in a column too, so that instead of displaying the value 25 in the [Ticket Count] column, I will get the list of all 25 Ticket IDs included. That should be continued for all following months, so I can set up a relationship based on the ticket ids between this table and my main Fact_Table in order to retrieve further information. 

Does anybody have an idea how I need to adjust my DAX code for the table or alternatively set up a measure in my main fact_table to achieve the desired result? 

Appreciate your help - Thank you very much!

1 ACCEPTED SOLUTION
Jihwan_Kim
Super User
Super User

Hi,

I am not sure if I understood your question correctly, but I tried to create a sample pbix file like below.

Please check the below picture and the attached pbix file. I hope the below can provide some ideas on how to create a solution for your datamodel.

 

Jihwan_Kim_0-1699382861318.png

 

 

expected result table = 
VAR _mindate =
    DATE ( YEAR ( MIN ( Data[Open_Month] ) ), 1, 1 )
VAR _maxdate =
    DATE ( YEAR ( MAX ( Data[Close_Month] ) ), 12, 31 )
VAR _t =
    ADDCOLUMNS (
        CALENDAR ( _mindate, _maxdate ),
        "month-year", FORMAT ( [Date], "mmm-yyyy" ),
        "month-year sort", EOMONTH ( [Date], 0 )
    )
RETURN
    SUMMARIZE (
        GENERATE (
            _t,
            FILTER ( Data, Data[Open_Month] <= [Date] && Data[Close_Month] >= [Date] )
        ),
        [month-year],
        [month-year sort],
        Data[Ticket ID]
    )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


View solution in original post

2 REPLIES 2
Jihwan_Kim
Super User
Super User

Hi,

I am not sure if I understood your question correctly, but I tried to create a sample pbix file like below.

Please check the below picture and the attached pbix file. I hope the below can provide some ideas on how to create a solution for your datamodel.

 

Jihwan_Kim_0-1699382861318.png

 

 

expected result table = 
VAR _mindate =
    DATE ( YEAR ( MIN ( Data[Open_Month] ) ), 1, 1 )
VAR _maxdate =
    DATE ( YEAR ( MAX ( Data[Close_Month] ) ), 12, 31 )
VAR _t =
    ADDCOLUMNS (
        CALENDAR ( _mindate, _maxdate ),
        "month-year", FORMAT ( [Date], "mmm-yyyy" ),
        "month-year sort", EOMONTH ( [Date], 0 )
    )
RETURN
    SUMMARIZE (
        GENERATE (
            _t,
            FILTER ( Data, Data[Open_Month] <= [Date] && Data[Close_Month] >= [Date] )
        ),
        [month-year],
        [month-year sort],
        Data[Ticket ID]
    )

If this post helps, then please consider accepting it as the solution to help other members find it faster, and give a big thumbs up.


Go to My LinkedIn Page


Hi Jihwan_Kim, 

 

thats exactly what I was looking for. I implemented your approach into my Power BI file and I got the desired result. 

Thank you very much for your help! 

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.