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

Earn a 50% discount on the DP-600 certification exam by completing the Fabric 30 Days to Learn It challenge.

Reply
735Alka
Frequent Visitor

distinct count of users who have their sales in each month in last six-month

Dear Community,

I have 3 years of sales data of users.

I have need to find the no. of users who have their sales each month in last 6 month.

Here is the sample data:

User CodeSales QunatityDate
337711012-03-2024
337741011-03-2024
337961028-02-2024
338021009-01-2024
338021013-03-2024
338031027-11-2023
338031013-09-2023
338421028-02-2024
338521001-08-2023
338541018-02-2024
338541025-02-2024
338901014-02-2024
339017.503-01-2024
339087.520-10-2023
438687.516-01-2024
443607.509-12-2023
337747.505-10-2023
575577.523-02-2024
578247.504-10-2023
588187.516-02-2024
708527.513-11-2023
337747.525-02-2024
33774920-01-2024
348811.2530-09-2023
4826811.2510-01-2024
148202528-02-2024
148892505-10-2023
148902527-02-2024
33122510-02-2024
335992509-01-2024
337742529-09-2023
337742506-03-2024
337902512-03-2024
337967.504-02-2024
337967.524-01-2024
3377411.2520-10-2023
3381211.2530-11-2023
338381008-11-2023
338411006-11-2023
338711027-02-2024
338711022-01-2024
338901018-08-2023
339087.518-12-2023
339087.512-11-2023
339157.531-12-2023
339277.515-01-2024
33927830-11-2023
33929802-01-2024
339481106-03-2024
339481413-01-2024
339645013-01-2024
337711912-03-2024
338021910-02-2024
338031906-03-2024
338031930-09-2023
338421914-10-2023
338521928-02-2024
338541904-10-2023
338541916-02-2024
338541919-11-2023
338901912-03-2024
338921914-12-2023
337741930-12-2023
339081903-11-2023
339081911-02-2024
339141906-02-2024
339151923-12-2023
4436019.9526-12-2023
7085219.9507-10-2023
3377419.9503-11-2023
348819.9509-08-2023
348819.9518-12-2023
4826819.9512-12-2023
1478219.9516-01-2024
1478219.9525-08-2023
1482019.9513-02-2024
1488919.9508-02-2024
1489022.0526-12-2023
331222.0530-11-2023
3377422.0530-11-2023
3380323.113-09-2023
3381223.112-11-2023
3384123.131-12-2023
3387123.115-01-2024
3387123.112-01-2024
3390123.130-10-2023
3390123.112-03-2024
3390823.111-02-2024
3391523.105-11-2023
3391523.109-03-2024
3377423.109-12-2023
3392723.108-01-2024
3392923.109-11-2023
3394823.102-03-2024
3394823.131-12-2023
3394823.123-10-2023
3398423.106-09-2023
3401323.127-02-2024
4273923.105-03-2024
4514823.114-02-2024
5809223.109-12-2023
6621223.101-11-2023
6621723.101-03-2024
5524324.1525-01-2024
12195525.212-08-2023
1489026.2508-11-2023
333626.2528-02-2024
334626.2504-10-2023
3359926.2511-01-2024
336726.2505-11-2023
340426.2512-03-2024
344626.2518-02-2024
348926.2513-11-2023
4305626.2509-02-2024
4386826.2502-02-2024
4434226.2502-02-2024
4436026.2508-09-2023
3379626.2527-02-2024
3380226.2507-03-2024
3380326.2514-12-2023
3381226.2509-02-2024
3381226.2531-08-2023

and this is the no. of users that i need to find based on sample data in power bi 

735Alka_0-1712726878018.png

Thanks!

2 ACCEPTED SOLUTIONS
johnbasha33
Solution Sage
Solution Sage

@735Alka 

Create a new calculated column in your table to extract the month and year from the Date column. You can use the following DAX formula:
MonthYear = FORMAT('Table'[Date], "YYYY-MM")

Next, create a new measure to count the distinct number of users who have sales in each month. You can use the following DAX formula:
DistinctUsersLast6Months =
CALCULATE(
DISTINCTCOUNT('Table'[User Code]),
FILTER(
ALL('Table'),
'Table'[MonthYear] >= FORMAT(TODAY() - 6 * 30, "YYYY-MM") &&
'Table'[MonthYear] <= FORMAT(TODAY(), "YYYY-MM") &&
'Table'[Sales Quantity] > 0
)
)

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


View solution in original post

v-tangjie-msft
Community Support
Community Support

Hi @735Alka ,

 

Thanks @johnbasha33  for the quick reply!

(1) This is my test data.  

vtangjiemsft_0-1712825834959.png

(2) We can create measures.

Measure = VAR A= SUMMARIZE(ADDCOLUMNS(CALENDAR(EOMONTH(TODAY(),-5),TODAY()),"Format",FORMAT([Date],"YYYY-MM")),[Format])
VAR B=ADDCOLUMNS(A,"TEST",CONCATENATEX(FILTER(ALLSELECTED('Table'),FORMAT([Date],"YYYY-MM") =EARLIER([Format])),[User Code],","))
RETURN COUNTROWS(FILTER(B,CONTAINSSTRING([TEST],MAX('Table'[User Code]))))
DistinctUsersLast6Months = CALCULATE(DISTINCTCOUNT('Table'[User Code]),FILTER('Table',[Measure]=6))

(3) Then the result is as follows.

vtangjiemsft_1-1712825883634.png

Best Regards,

Neeko Tang

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

2 REPLIES 2
v-tangjie-msft
Community Support
Community Support

Hi @735Alka ,

 

Thanks @johnbasha33  for the quick reply!

(1) This is my test data.  

vtangjiemsft_0-1712825834959.png

(2) We can create measures.

Measure = VAR A= SUMMARIZE(ADDCOLUMNS(CALENDAR(EOMONTH(TODAY(),-5),TODAY()),"Format",FORMAT([Date],"YYYY-MM")),[Format])
VAR B=ADDCOLUMNS(A,"TEST",CONCATENATEX(FILTER(ALLSELECTED('Table'),FORMAT([Date],"YYYY-MM") =EARLIER([Format])),[User Code],","))
RETURN COUNTROWS(FILTER(B,CONTAINSSTRING([TEST],MAX('Table'[User Code]))))
DistinctUsersLast6Months = CALCULATE(DISTINCTCOUNT('Table'[User Code]),FILTER('Table',[Measure]=6))

(3) Then the result is as follows.

vtangjiemsft_1-1712825883634.png

Best Regards,

Neeko Tang

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

johnbasha33
Solution Sage
Solution Sage

@735Alka 

Create a new calculated column in your table to extract the month and year from the Date column. You can use the following DAX formula:
MonthYear = FORMAT('Table'[Date], "YYYY-MM")

Next, create a new measure to count the distinct number of users who have sales in each month. You can use the following DAX formula:
DistinctUsersLast6Months =
CALCULATE(
DISTINCTCOUNT('Table'[User Code]),
FILTER(
ALL('Table'),
'Table'[MonthYear] >= FORMAT(TODAY() - 6 * 30, "YYYY-MM") &&
'Table'[MonthYear] <= FORMAT(TODAY(), "YYYY-MM") &&
'Table'[Sales Quantity] > 0
)
)

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


Helpful resources

Announcements
LearnSurvey

Fabric certifications survey

Certification feedback opportunity for the community.

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.

Top Solution Authors