March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
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 Code | Sales Qunatity | Date |
33771 | 10 | 12-03-2024 |
33774 | 10 | 11-03-2024 |
33796 | 10 | 28-02-2024 |
33802 | 10 | 09-01-2024 |
33802 | 10 | 13-03-2024 |
33803 | 10 | 27-11-2023 |
33803 | 10 | 13-09-2023 |
33842 | 10 | 28-02-2024 |
33852 | 10 | 01-08-2023 |
33854 | 10 | 18-02-2024 |
33854 | 10 | 25-02-2024 |
33890 | 10 | 14-02-2024 |
33901 | 7.5 | 03-01-2024 |
33908 | 7.5 | 20-10-2023 |
43868 | 7.5 | 16-01-2024 |
44360 | 7.5 | 09-12-2023 |
33774 | 7.5 | 05-10-2023 |
57557 | 7.5 | 23-02-2024 |
57824 | 7.5 | 04-10-2023 |
58818 | 7.5 | 16-02-2024 |
70852 | 7.5 | 13-11-2023 |
33774 | 7.5 | 25-02-2024 |
33774 | 9 | 20-01-2024 |
3488 | 11.25 | 30-09-2023 |
48268 | 11.25 | 10-01-2024 |
14820 | 25 | 28-02-2024 |
14889 | 25 | 05-10-2023 |
14890 | 25 | 27-02-2024 |
3312 | 25 | 10-02-2024 |
33599 | 25 | 09-01-2024 |
33774 | 25 | 29-09-2023 |
33774 | 25 | 06-03-2024 |
33790 | 25 | 12-03-2024 |
33796 | 7.5 | 04-02-2024 |
33796 | 7.5 | 24-01-2024 |
33774 | 11.25 | 20-10-2023 |
33812 | 11.25 | 30-11-2023 |
33838 | 10 | 08-11-2023 |
33841 | 10 | 06-11-2023 |
33871 | 10 | 27-02-2024 |
33871 | 10 | 22-01-2024 |
33890 | 10 | 18-08-2023 |
33908 | 7.5 | 18-12-2023 |
33908 | 7.5 | 12-11-2023 |
33915 | 7.5 | 31-12-2023 |
33927 | 7.5 | 15-01-2024 |
33927 | 8 | 30-11-2023 |
33929 | 8 | 02-01-2024 |
33948 | 11 | 06-03-2024 |
33948 | 14 | 13-01-2024 |
33964 | 50 | 13-01-2024 |
33771 | 19 | 12-03-2024 |
33802 | 19 | 10-02-2024 |
33803 | 19 | 06-03-2024 |
33803 | 19 | 30-09-2023 |
33842 | 19 | 14-10-2023 |
33852 | 19 | 28-02-2024 |
33854 | 19 | 04-10-2023 |
33854 | 19 | 16-02-2024 |
33854 | 19 | 19-11-2023 |
33890 | 19 | 12-03-2024 |
33892 | 19 | 14-12-2023 |
33774 | 19 | 30-12-2023 |
33908 | 19 | 03-11-2023 |
33908 | 19 | 11-02-2024 |
33914 | 19 | 06-02-2024 |
33915 | 19 | 23-12-2023 |
44360 | 19.95 | 26-12-2023 |
70852 | 19.95 | 07-10-2023 |
33774 | 19.95 | 03-11-2023 |
3488 | 19.95 | 09-08-2023 |
3488 | 19.95 | 18-12-2023 |
48268 | 19.95 | 12-12-2023 |
14782 | 19.95 | 16-01-2024 |
14782 | 19.95 | 25-08-2023 |
14820 | 19.95 | 13-02-2024 |
14889 | 19.95 | 08-02-2024 |
14890 | 22.05 | 26-12-2023 |
3312 | 22.05 | 30-11-2023 |
33774 | 22.05 | 30-11-2023 |
33803 | 23.1 | 13-09-2023 |
33812 | 23.1 | 12-11-2023 |
33841 | 23.1 | 31-12-2023 |
33871 | 23.1 | 15-01-2024 |
33871 | 23.1 | 12-01-2024 |
33901 | 23.1 | 30-10-2023 |
33901 | 23.1 | 12-03-2024 |
33908 | 23.1 | 11-02-2024 |
33915 | 23.1 | 05-11-2023 |
33915 | 23.1 | 09-03-2024 |
33774 | 23.1 | 09-12-2023 |
33927 | 23.1 | 08-01-2024 |
33929 | 23.1 | 09-11-2023 |
33948 | 23.1 | 02-03-2024 |
33948 | 23.1 | 31-12-2023 |
33948 | 23.1 | 23-10-2023 |
33984 | 23.1 | 06-09-2023 |
34013 | 23.1 | 27-02-2024 |
42739 | 23.1 | 05-03-2024 |
45148 | 23.1 | 14-02-2024 |
58092 | 23.1 | 09-12-2023 |
66212 | 23.1 | 01-11-2023 |
66217 | 23.1 | 01-03-2024 |
55243 | 24.15 | 25-01-2024 |
121955 | 25.2 | 12-08-2023 |
14890 | 26.25 | 08-11-2023 |
3336 | 26.25 | 28-02-2024 |
3346 | 26.25 | 04-10-2023 |
33599 | 26.25 | 11-01-2024 |
3367 | 26.25 | 05-11-2023 |
3404 | 26.25 | 12-03-2024 |
3446 | 26.25 | 18-02-2024 |
3489 | 26.25 | 13-11-2023 |
43056 | 26.25 | 09-02-2024 |
43868 | 26.25 | 02-02-2024 |
44342 | 26.25 | 02-02-2024 |
44360 | 26.25 | 08-09-2023 |
33796 | 26.25 | 27-02-2024 |
33802 | 26.25 | 07-03-2024 |
33803 | 26.25 | 14-12-2023 |
33812 | 26.25 | 09-02-2024 |
33812 | 26.25 | 31-08-2023 |
and this is the no. of users that i need to find based on sample data in power bi
Thanks!
Solved! Go to Solution.
@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 !!
Hi @735Alka ,
Thanks @johnbasha33 for the quick reply!
(1) This is my test data.
(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.
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.
Hi @735Alka ,
Thanks @johnbasha33 for the quick reply!
(1) This is my test data.
(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.
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.
@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 !!
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
23 | |
16 | |
12 | |
9 | |
7 |
User | Count |
---|---|
38 | |
32 | |
28 | |
12 | |
11 |