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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
ekaponkratova
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
v-shex-msft
Community Support
Community Support

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
If this post helps, please consider accept as solution to help other members find it more quickly.

View solution in original post

1 REPLY 1
v-shex-msft
Community Support
Community Support

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
If this post helps, please consider accept as solution to help other members find it more quickly.

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

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.