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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
James__
Frequent Visitor

Help in Identifying Renewal Customers

Hi,

 

I have a list of policy sales and i need to identify which customers have renewed. Each policy is 12 months in duration and each customer has an unique ID.

 

Can anyone help identify which policy have been renewed? I'd like to sum this data and the turn it into a percentage, which is the easy bit. I'm just struggling to write the measure to idenify renewed customers.

 

Sample data:

 

James___0-1664952435867.png

 

1 ACCEPTED SOLUTION

Try this measure:

Renewed =
VAR _ID =
    MAX ( 'Table'[Unique ID] )
VAR _Reg =
    MAX ( 'Table'[Reg] )
VAR _Renewed =
    IF (
        COUNTROWS (
            SUMMARIZE (
                FILTER ( ALL ( 'Table' ), 'Table'[Unique ID] = _ID && 'Table'[Reg] = _Reg ),
                'Table'[Unique ID],
                'Table'[Reg],
                'Table'[Inception Date]
            )
        ) > 1,
        "Renewed"
    )
VAR _date =
    CALCULATE (
        MAX ( 'Table'[Inception Date] ),
        FILTER ( ALLEXCEPT ( 'Table', 'Table'[Unique ID] ), NOT ISBLANK ( _Renewed ) )
    )
RETURN
    IF ( MAX ( 'Table'[Inception Date] ) = _date, _date )

result.png

 





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






View solution in original post

4 REPLIES 4
James__
Frequent Visitor

Unique IDRegPolicy CountProductInception DateIs_renewal (1,0)   
ABC123NU72CAR1MOT Cover01/01/20210   
ABC124NU72CAB1MOT Cover01/01/20220   
ABC125NU72CAC1MOT Cover01/01/20220   
ABC123NU72CAR1MOT Cover01/01/20221   
         
         
         
         
         

 

As you can see, unique user ABC123 has renewed their product. Initial product has an inception date of 01/01/2021 and the renewal product has an inception date of 01/01/2022. The vehicle reg is the same, which is important. 

Try this measure:

Renewed =
VAR _ID =
    MAX ( 'Table'[Unique ID] )
VAR _Reg =
    MAX ( 'Table'[Reg] )
VAR _Renewed =
    IF (
        COUNTROWS (
            SUMMARIZE (
                FILTER ( ALL ( 'Table' ), 'Table'[Unique ID] = _ID && 'Table'[Reg] = _Reg ),
                'Table'[Unique ID],
                'Table'[Reg],
                'Table'[Inception Date]
            )
        ) > 1,
        "Renewed"
    )
VAR _date =
    CALCULATE (
        MAX ( 'Table'[Inception Date] ),
        FILTER ( ALLEXCEPT ( 'Table', 'Table'[Unique ID] ), NOT ISBLANK ( _Renewed ) )
    )
RETURN
    IF ( MAX ( 'Table'[Inception Date] ) = _date, _date )

result.png

 





Did I answer your question? Mark my post as a solution!
In doing so, you are also helping me. Thank you!

Proud to be a Super User!
Paul on Linkedin.






Thanks @PaulDBrown that did the job.

amitchandak
Super User
Super User

@James__ ,
Can you please share sample data and sample output in table format?

Helpful resources

Announcements
Fabcon_Europe_Social_Bogo

Europe’s largest Microsoft Fabric Community Conference

Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.

Power BI Carousel June 2024

Power BI Monthly Update - June 2024

Check out the June 2024 Power BI update to learn about new features.

PBI_Carousel_NL_June

Fabric Community Update - June 2024

Get the latest Fabric updates from Build 2024, key Skills Challenge voucher deadlines, top blogs, forum posts, and product ideas.

RTI Forums Carousel3

New forum boards available in Real-Time Intelligence.

Ask questions in Eventhouse and KQL, Eventstream, and Reflex.