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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
Anonymous
Not applicable

How to get the Last Value of a Column Per ID, where Date is less than another date

Hi there,

 

Trying to figure out how I can get the Last Value of a Column Per Deal ID, where Date is less than another date. I'm good with either a column or a measure, but would like the measure to generate a value for each Deal Id.

 

Here is a sample of the data with the desired column is Last Campaign Before Deal Date:

 

AccountIDDealIDCampaignRespondedDateDeal DateLast Campaign Before Deal Date
0016100001MWwQdAAL0065W000002CWrsQAGCamp 111/19/201910/19/2020Camp 2
0016100001MWwQdAAL0065W000002CWrsQAGCamp 210/13/202010/19/2020Camp 2
0016100001MWwQdAAL0065W000002CWrsQAGCamp 310/20/202010/19/2020Camp 2
0016100001KhVELAA30065W0000024vAMQAYCamp 39/30/201910/1/2019Camp 3
0016100001KhVELAA30065W0000024vAMQAYCamp 39/30/201910/1/2019Camp 3
0016100001KhVELAA30065W000002kgGqQAICamp 310/30/201911/1/2019Camp 3
0016100001KhVELAA30065W000002kgGqQAICamp 411/30/201911/1/2019Camp 3

 

I attempted using CONCATENATEX, but it returns a string of values:

 

 

 

LastCampaign (Attempt 1) = 
VAR LastTouchDate =
    VALUES ( CampaignMembersAllPipeGen[LastTouchDate] )
VAR Deals =
    VALUES ( CampaignMembersAllPipeGen[DealId] )
RETURN 
    CONCATENATEX (

        CALCULATETABLE(DISTINCT(CampaignMembersAllPipeGen[Campaign]),        FILTER (
            ALL ( CampaignMembersAllPipeGen ),
            CampaignMembersAllPipeGen[RespondedDate]
                IN FirstTouchDate
                && CampaignMembersAllPipeGen[DealId] IN Deals
        ))
, CampaignMembersAllPipeGen[Campaign],

        "---"
    )

 

 

 

I also tried this but it only returns a single value vs. a list of values which is desired per Deal ID. Also this doesn't include the less than the other date parameter.

 

 

 

Last Campaign (Attempt 2) = 
VAR LastTouchDate =
    VALUES ( CampaignMembersAllPipeGen[LastTouchDate] )
VAR Deals =
    VALUES ( CampaignMembersAllPipeGen[DealId] )
RETURN 
    LASTNONBLANK( 

        CALCULATETABLE(DISTINCT(CampaignMembersAllPipeGen[Campaign]),        FILTER (
            ALL ( CampaignMembersAllPipeGen ),
            CampaignMembersAllPipeGen[RespondedDate]
                IN LastTouchDate
                && CampaignMembersAllPipeGen[DealId] IN Deals
        ))

    ,0)

 

 

 

Thank you for reviewing my question appreciate an help you can provide!

1 ACCEPTED SOLUTION
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

You could use this measure

M Last Campaign Before Deal Date = 
VAR vDealDate =
    MAX ( 'Table'[Deal Date] )
VAR vLastDate =
    CALCULATE (
        MAX ( 'Table'[RespondedDate] ),
        ALLEXCEPT ( 'Table', 'Table'[DealID] ),
        'Table'[RespondedDate] < vDealDate
    )
VAR vResult =
    CALCULATE (
        MAX ( 'Table'[Campaign] ),
        ALLEXCEPT ( 'Table', 'Table'[DealID] ),
        'Table'[RespondedDate] = vLastDate
    )
RETURN
    vResult

21093003.jpg

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

View solution in original post

2 REPLIES 2
v-jingzhang
Community Support
Community Support

Hi @Anonymous 

 

You could use this measure

M Last Campaign Before Deal Date = 
VAR vDealDate =
    MAX ( 'Table'[Deal Date] )
VAR vLastDate =
    CALCULATE (
        MAX ( 'Table'[RespondedDate] ),
        ALLEXCEPT ( 'Table', 'Table'[DealID] ),
        'Table'[RespondedDate] < vDealDate
    )
VAR vResult =
    CALCULATE (
        MAX ( 'Table'[Campaign] ),
        ALLEXCEPT ( 'Table', 'Table'[DealID] ),
        'Table'[RespondedDate] = vLastDate
    )
RETURN
    vResult

21093003.jpg

 

Best Regards,
Community Support Team _ Jing
If this post helps, please Accept it as Solution to help other members find it.

DataInsights
Super User
Super User

@Anonymous,

 

Try this measure:

 

Last Campaign Before Deal Date = 
VAR vDealDate =
    MAX ( CampaignMembersAllPipeGen[Deal Date] )
VAR vResult =
    CALCULATE (
        MAX ( CampaignMembersAllPipeGen[Campaign] ),
        ALLEXCEPT ( CampaignMembersAllPipeGen, CampaignMembersAllPipeGen[DealID] ),
        CampaignMembersAllPipeGen[RespondedDate] < vDealDate
    )
RETURN
    vResult

 

DataInsights_0-1632490237726.png

 





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

Proud to be a Super User!




Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 2025 Power BI update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors
Top Kudoed Authors