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

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply

Get only matching month and year of other column

I have two date column,
one column has month-year and another column is weekend-dates, like below image

newlearnpbi123_0-1702131509931.png

 

i want to have only one matching month and year of the month column, like below

newlearnpbi123_1-1702131718035.png

 

the issue is starting of month and end of month sometimes present in previous month as highlighted in first image,

can someone help me get the result of 2nd image, any date is fine as long it is only one date matching the month column, so i could use it in  my slicer.

 

@PaulDBrown 

1 ACCEPTED SOLUTION
PaulDBrown
Community Champion
Community Champion

Here is one way.

1) a measure for the date : 

Date Measure = MAX('Table'[wk_end_dt])
2) A measure to get the second date by month (to avoid the issue of having a date from the previous month in the scope of the following month)

 

 

2Wk Date =
VAR _Month =
    MAX ( 'Table'[Month] )
VAR _RNK =
    RANKX (
        FILTER ( ALL ( 'Table' ), 'Table'[Month] = _Month ),
        [Date Measure],
        ,
        ASC
    )
RETURN
    CALCULATE (
        [Date Measure],
        FILTER ( ALL ( 'Table'[Month] ), 'Table'[Month] = _Month && _RNK = 2 )
    )

 

 

3) and a final measure to display this date by month

 

 

2wk date by month =
    MAXX (
        SUMMARIZE ( 'Table', 'Table'[Month], 'Table'[wk_end_dt], "_okDate", [2Wk Date] ),
        [_okDate]
    )

 

 

 

Captura de pantalla 2023-12-10 113816.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

2 REPLIES 2
PaulDBrown
Community Champion
Community Champion

Here is one way.

1) a measure for the date : 

Date Measure = MAX('Table'[wk_end_dt])
2) A measure to get the second date by month (to avoid the issue of having a date from the previous month in the scope of the following month)

 

 

2Wk Date =
VAR _Month =
    MAX ( 'Table'[Month] )
VAR _RNK =
    RANKX (
        FILTER ( ALL ( 'Table' ), 'Table'[Month] = _Month ),
        [Date Measure],
        ,
        ASC
    )
RETURN
    CALCULATE (
        [Date Measure],
        FILTER ( ALL ( 'Table'[Month] ), 'Table'[Month] = _Month && _RNK = 2 )
    )

 

 

3) and a final measure to display this date by month

 

 

2wk date by month =
    MAXX (
        SUMMARIZE ( 'Table', 'Table'[Month], 'Table'[wk_end_dt], "_okDate", [2Wk Date] ),
        [_okDate]
    )

 

 

 

Captura de pantalla 2023-12-10 113816.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.






thank you sir @PaulDBrown 

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.