Join us at FabCon Atlanta from March 16 - 20, 2026, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.
Register now!To celebrate FabCon Vienna, we are offering 50% off select exams. Ends October 3rd. Request your discount now.
I have a customer legal id detail table which have cust_id,leagal_id,Legal_id expiry_date,review_date. I have calculated a column expired_days and bucket based on group of 30 days. Now I want to find the count of id moving from one bucket to another bucket over month and in the same how many are newly moved id count and how many are existing id count by bucket over month.
Solved! Go to Solution.
Hi @Babu_s22
Please try this:
Here's the sample data:
Then add a new table:
Table 2 =
VAR _vtable = ADDCOLUMNS(
'Table',
"_ABC", VAR _Previous = CALCULATE(
MAX('Table'[review_date]),
FILTER(
ALLSELECTED('Table'),
'Table'[cust_id] = EARLIER('Table'[cust_id]) && 'Table'[review_date] < EARLIER('Table'[review_date])
)
)
RETURN
IF(
_Previous <> BLANK() && 'Table'[Days_Buckets] <> CALCULATE(
SELECTEDVALUE('Table'[Days_Buckets]),
FILTER(
ALLSELECTED('Table'),
'Table'[cust_id] = EARLIER('Table'[cust_id]) && 'Table'[review_date] = _Previous
)
),
1,
0
)
)
RETURN
SUMMARIZE(
SELECTCOLUMNS(
_vtable,
"_Month", FORMAT(
'Table'[review_date],
"YYYY-mm"
),
"_PreviousCount", COUNTX(
FILTER(
_vtable,
MONTH([review_date]) = MONTH(EARLIER('Table'[review_date])) && [_ABC] = 1
),
[cust_id]
),
"_CurrentCount", COUNTX(
FILTER(
_vtable,
MONTH([review_date]) = MONTH(EARLIER([review_date]))
),
[cust_id]
)
),
[_Month],
[_PreviousCount],
[_CurrentCount]
)
The result is as follow:
Best Regards
Zhengdong Xu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @Babu_s22
Please try this:
Here's the sample data:
Then add a new table:
Table 2 =
VAR _vtable = ADDCOLUMNS(
'Table',
"_ABC", VAR _Previous = CALCULATE(
MAX('Table'[review_date]),
FILTER(
ALLSELECTED('Table'),
'Table'[cust_id] = EARLIER('Table'[cust_id]) && 'Table'[review_date] < EARLIER('Table'[review_date])
)
)
RETURN
IF(
_Previous <> BLANK() && 'Table'[Days_Buckets] <> CALCULATE(
SELECTEDVALUE('Table'[Days_Buckets]),
FILTER(
ALLSELECTED('Table'),
'Table'[cust_id] = EARLIER('Table'[cust_id]) && 'Table'[review_date] = _Previous
)
),
1,
0
)
)
RETURN
SUMMARIZE(
SELECTCOLUMNS(
_vtable,
"_Month", FORMAT(
'Table'[review_date],
"YYYY-mm"
),
"_PreviousCount", COUNTX(
FILTER(
_vtable,
MONTH([review_date]) = MONTH(EARLIER('Table'[review_date])) && [_ABC] = 1
),
[cust_id]
),
"_CurrentCount", COUNTX(
FILTER(
_vtable,
MONTH([review_date]) = MONTH(EARLIER([review_date]))
),
[cust_id]
)
),
[_Month],
[_PreviousCount],
[_CurrentCount]
)
The result is as follow:
Best Regards
Zhengdong Xu
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
https://www.daxpatterns.com/new-and-returning-customers/
Please provide sample data that covers your issue or question completely, in a usable format (not as a screenshot).
Do not include sensitive information. Do not include anything that is unrelated to the issue or question.
Need help uploading data? https://community.fabric.microsoft.com/t5/Community-Blog/How-to-provide-sample-data-in-the-Power-BI-...
Please show the expected outcome based on the sample data you provided.
Want faster answers? https://community.fabric.microsoft.com/t5/Desktop/How-to-Get-Your-Question-Answered-Quickly/m-p/1447...