Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowGet inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.
Hi, I have the below fields in my credit cards table.
Customer ID
Card Open Date
Account Status
I need to create a new column Account Status Updated when a customer has more than one cards with Active status. If that happens then I need to check the maximum Card Open date and update only that has Active. Remaining I need to update as Closed.
In the below example, customer AE0001 has two cards with Active status. One card open date is 01-Jan-20 and another with 01-Feb-21. I need to make the 01-Feb-21 opened card as active since it is the latest date. Old cards need to be closed.
The customer AE0002 also has two cards but it only one is Active. So it does not come to our case and so the same status is updated in Account Status Updated column too.
Please help.
Customer ID | Card Open Date | Account Status | Account Status Updated |
AE0001 | 01-Jan-20 | Active | Closed |
AE0001 | 01-Feb-21 | Active | Active |
AE0002 | 01-Mar-20 | Active | Active |
AE0002 | 01-Mar-21 | Closed | Closed |
AE0003 | 01-Mar-20 | Closed | Closed |
AE0003 | 01-Mar-21 | Active | Active |
AE0004 | 01-Mar-21 | Active | Active |
AE0005 | 01-Mar-21 | Closed | Closed |
Solved! Go to Solution.
Hi, @Anonymous
You can try the following methods.
Account Status Updated =
IF (
CALCULATE (
COUNT ( 'Table'[Account Status] ),
FILTER (
'Table',
[Customer ID] = EARLIER ( 'Table'[Customer ID] )
&& [Account Status] = "Active"
)
) > 1,
IF (
[Card Open Date]
= CALCULATE (
MIN ( 'Table'[Card Open Date] ),
FILTER ( 'Table', [Customer ID] = EARLIER ( 'Table'[Customer ID] ) )
),
"Closed",
[Account Status]
),
[Account Status]
)
The output you expect is shown in the figure.
Best Regards,
Community Support Team _Charlotte
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi, @Anonymous
You can try the following methods.
Account Status Updated =
IF (
CALCULATE (
COUNT ( 'Table'[Account Status] ),
FILTER (
'Table',
[Customer ID] = EARLIER ( 'Table'[Customer ID] )
&& [Account Status] = "Active"
)
) > 1,
IF (
[Card Open Date]
= CALCULATE (
MIN ( 'Table'[Card Open Date] ),
FILTER ( 'Table', [Customer ID] = EARLIER ( 'Table'[Customer ID] ) )
),
"Closed",
[Account Status]
),
[Account Status]
)
The output you expect is shown in the figure.
Best Regards,
Community Support Team _Charlotte
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
@Anonymous , Try a new column like
New Status =
var _cnt = count(filter(Table,[Customer ID] =earlier([Customer ID]) && [Card Open Date] > earlier([Card Open Date]) && [Status] ="Active"),[Cusstomer ID])
return
if(isblank(_cnt), [Status], "Closed")
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code FABINSIDER for a $400 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
86 | |
69 | |
66 | |
51 | |
32 |
User | Count |
---|---|
114 | |
99 | |
75 | |
65 | |
40 |