cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Highlighted
ekaponkratova Frequent Visitor
Frequent Visitor

Return first non blank date per account per group

I have a dataset:

1.png

How can I get the first non-blank date per account?

3.png

1 ACCEPTED SOLUTION

Accepted Solutions
Community Support Team
Community Support Team

Re: Return first non blank date per account per group

Hi @ekaponkratova ,

According to your snapshot, did you mean you want to get the first date for each continuous date range per account group?

If this is a case, does your table data group are stored with continuous date or random date collection?

If you mean continuous data, you can write calculate columns to use date as index to looping table records and mark tag. (is continuous)

isContinuous =
VAR previous =
    LOOKUPVALUE ( [Date], T3[id], [id], T3[Date], [Date] - 1 )
VAR next =
    LOOKUPVALUE ( [Date], T3[id], [id], T3[Date], [Date] + 1 )
RETURN
    IF (
        AND ( [Date] <> BLANK (), OR ( previous <> BLANK (), next <> BLANK () ) ),
        1,
        0
    )

Otherwise, you need to enter to query editor and add an index column for each account group.

isContinuous =
VAR previous =
    LOOKUPVALUE ( [Date], T3[id], [id], T3[Index], [Index] - 1 )
VAR next =
    LOOKUPVALUE ( [Date], T3[id], [id], T3[Index], [Index] + 1 )
RETURN
    IF (
        AND ( [Date] <> BLANK (), OR ( previous <> BLANK (), next <> BLANK () ) ),
        1,
        0
    )

After you finish creating IsContinuous column, you can simply write calculate column formula to use this field to lookup correspond records. (power bi data model does not contain column/row index to find out specific records)

First Continuous Date = 
IF (
    [isContinuous] = 1,
    VAR nearlest =
        CALCULATE (
            MAX ( T3[Index] ),
            FILTER (
                ALLSELECTED ( T3 ),
                [id] = AVERAGE ( T3[id] )
                    && [Index] < EARLIER ( T3[Index] )
                    && [isContinuous] = 0
            )
        )
    RETURN
        LOOKUPVALUE ( T3[Date], T3[id], [id], T3[Index], nearlest + 1 ),
    IF ( [isContinuous] = 0 && [Date] <> BLANK (), [Date] )
)

23.png

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin Sheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.



For learning resources/Release notes, please visit: | |

View solution in original post

1 REPLY 1
Community Support Team
Community Support Team

Re: Return first non blank date per account per group

Hi @ekaponkratova ,

According to your snapshot, did you mean you want to get the first date for each continuous date range per account group?

If this is a case, does your table data group are stored with continuous date or random date collection?

If you mean continuous data, you can write calculate columns to use date as index to looping table records and mark tag. (is continuous)

isContinuous =
VAR previous =
    LOOKUPVALUE ( [Date], T3[id], [id], T3[Date], [Date] - 1 )
VAR next =
    LOOKUPVALUE ( [Date], T3[id], [id], T3[Date], [Date] + 1 )
RETURN
    IF (
        AND ( [Date] <> BLANK (), OR ( previous <> BLANK (), next <> BLANK () ) ),
        1,
        0
    )

Otherwise, you need to enter to query editor and add an index column for each account group.

isContinuous =
VAR previous =
    LOOKUPVALUE ( [Date], T3[id], [id], T3[Index], [Index] - 1 )
VAR next =
    LOOKUPVALUE ( [Date], T3[id], [id], T3[Index], [Index] + 1 )
RETURN
    IF (
        AND ( [Date] <> BLANK (), OR ( previous <> BLANK (), next <> BLANK () ) ),
        1,
        0
    )

After you finish creating IsContinuous column, you can simply write calculate column formula to use this field to lookup correspond records. (power bi data model does not contain column/row index to find out specific records)

First Continuous Date = 
IF (
    [isContinuous] = 1,
    VAR nearlest =
        CALCULATE (
            MAX ( T3[Index] ),
            FILTER (
                ALLSELECTED ( T3 ),
                [id] = AVERAGE ( T3[id] )
                    && [Index] < EARLIER ( T3[Index] )
                    && [isContinuous] = 0
            )
        )
    RETURN
        LOOKUPVALUE ( T3[Date], T3[id], [id], T3[Index], nearlest + 1 ),
    IF ( [isContinuous] = 0 && [Date] <> BLANK (), [Date] )
)

23.png

Regards,

Xiaoxin Sheng

Community Support Team _ Xiaoxin Sheng
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.



For learning resources/Release notes, please visit: | |

View solution in original post

Helpful resources

Announcements
New Kudos Received Badges Coming

New Kudos Received Badges Coming

Kudos to you if you earned one of these! Check your inbox for a notification.

Microsoft Implementation for Communities Wins Award

Microsoft Implementation for Communities Wins Award

Learn about the award-winning innovation that was implemented across Microsoft’s Business Applications Communities.

Power Platform World Tour

Power Platform World Tour

Find out where you can attend!

Top Kudoed Authors (Last 30 Days)
Users online (2,543)