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

Counting Active in non calendar date range

I've read through a number of similar posts, but none quite fits my scenario, and having poked and prodded, I can't make them fit.

 

I have a USER table with Username, Creation date, Expiry date. Where Username is a string, Create date is a date/time and Expiry date is a date/time. The Expiry date could be blank.

e.g.

UsernameCreation DateExpiry Date
Person A03/02/202305/06/2023
Person B06/02/202307/02/2023
Person C10/03/202309/05/2023
Person D15/03/2023 
Person E25/03/202326/03/2023

 

I have a BILLING table with Start Date, End Date, Billing Period. This represents our billing periods, which run from 26th of eachmonth to 25th of the next. Billing period is purely a numeric "label" to give the billing period a name of sorts.

e.g.

 

Start DateEnd DateBilling Period
26/01/202325/02/20231
26/02/202325/03/20232
26/03/202325/04/20233
26/04/202325/05/20234
26/05/202325/06/20235
26/06/202325/07/20236

 

The tables are not related.

 

What I would like to show is the number of Active accounts per billing period. Where an active account is deemed to be on or after the date of creation, and before or on the date of expiry.

 

This  would result in a table that looks like this:

Billing PeriodActive UsersMy explaination (not in the visual)
12Person A and B both count
24Person A, C, D and E were all created within the billing period, but person B expired during period 1 so is not counted.
34Person A, C, D and E have days active in this billing period before their expiry date even Person E because they expire on the first day of this billing period, hence are still in it.
43Person E expired in the previous billing period, leaving only A, C and D
52Person C expired in the previous billing period, so only A and D are left
61Only person D, with no expiry date, is left here.

 

Hope this makes sense.

Thank you in advance for any help you may be able to offer.

 

Best,

Marion

1 ACCEPTED SOLUTION
v-kaiyue-msft
Community Support
Community Support

Hi @MarionC ,

 

Your solution is great, @audreygerred . Here I have another idea that I want to share for reference.


You can create a measure to count users.

Active Accounts =
CALCULATE(
COUNTROWS('USER'),
FILTER(
'USER',
'USER'[Creation Date] <= MAX('BILLING'[End Date]) &&
(ISBLANK('USER'[Expiry Date]) || 'USER'[Expiry Date] >= MIN('BILLING'[Start Date]))
)
)

 

vkaiyuemsft_0-1714542255654.png

If your Current Period does not refer to this, please clarify in a follow-up reply.

 

Best Regards,

Clara Gong

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

3 REPLIES 3
MarionC
New Member

Thank you both for your help! I was so close with my own explorations, but you nailed it, and gave me more information to help me learn.

v-kaiyue-msft
Community Support
Community Support

Hi @MarionC ,

 

Your solution is great, @audreygerred . Here I have another idea that I want to share for reference.


You can create a measure to count users.

Active Accounts =
CALCULATE(
COUNTROWS('USER'),
FILTER(
'USER',
'USER'[Creation Date] <= MAX('BILLING'[End Date]) &&
(ISBLANK('USER'[Expiry Date]) || 'USER'[Expiry Date] >= MIN('BILLING'[Start Date]))
)
)

 

vkaiyuemsft_0-1714542255654.png

If your Current Period does not refer to this, please clarify in a follow-up reply.

 

Best Regards,

Clara Gong

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

audreygerred
Super User
Super User

Hi! Check out this YouTube video - it has helped me with something similar: https://youtu.be/pQ9eSnfAhnc?si=YZBEyoJzdS_HS3pV




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

Proud to be a Super User!





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.