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
trt18-sistemas
Advocate III
Advocate III

Error using slicer to filter between start and end dates

Hi there,

 

I'd like to report a error at Power BI Desktop.
I have one table (Vagas) that contains a list of Vagas with starting and ending dates (Data de Criação e Data de Extinção, respectivelly) whereas ending dates may have a value or is blank. The source table is available here: https://docs.google.com/spreadsheets/d/e/2PACX-1vSm3SItLuNvsXCMqsbKoLkQuzjkqCFc67kf5wSzWms7EVneHges_...

What I need is to list the items that were active in a specific month-year. To solve this, I've copied that solution https://community.powerbi.com/t5/Desktop/FILTERING-date-cycles-start-and-end-given/m-p/770436#M37124...which is quite similar as mine.

In summary, the solution above consists in creating a Calendar table and add 3 columns: year (ano), month (mês) and year-month (ano-mês). Year-month will be used as a field at the slicer.

Then you create a measure using the Calendar date and the starting and ending dates. 

Count of Issues =
VAR SelectedYear = SELECTEDVALUE(Calendario[Ano])
VAR SelectedMonth = SELECTEDVALUE(Calendario[Mes])
RETURN CALCULATE (
   COUNTROWS ( Vagas ),
   YEAR ( COALESCE(Vagas[Data Extinção], TODAY()) ) >= SelectedYear,
   YEAR ( Vagas[Data Criação] ) <= SelectedYear,
   MONTH ( COALESCE(Vagas[Data Extinção], TODAY() )) >= SelectedMonth, 
   MONTH ( Vagas[Data Criação] ) <= SelectedMonth
 )

 

Everything seems to work just fine, but when I select some spectific year-month filters, the visual table turns into blank. Check the images bellow.

PBI-ErroSliceDatesBetween03.JPG

 

This is the content of Vagas table. Those items that has no Data Extinção, must be listed in every situation. The others must be showned only if the slice date is between Data Criação e Data Exinção.

 

PBI-ErroSliceDatesBetween01.JPG

When I select 2000-01 it works just fine as in many other dates. Althougth, in other months, like 2000-09 (as image below), the table on the left is printed as blank.

 

PBI-ErroSliceDatesBetween02.JPG

 

for me, it is an error, isn't it?

 

 

 

 

 

 

 

 

1 ACCEPTED SOLUTION
v-alq-msft
Community Support
Community Support

Hi, @trt18-sistemas 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

e1.png

 

Calendar(a calculated table):

Calendar = CALENDARAUTO()

 

You may create calculated columns and a measure as below.

Calculated column:

Calendar Year Month = YEAR('Calendar'[Date])*100+MONTH('Calendar'[Date])
Start Year Month = YEAR('Table'[Start Date])*100+MONTH('Table'[Start Date])
End Year Month = YEAR('Table'[End Date])*100+MONTH('Table'[End Date])

 

Measure:

Visual Control = 
var _yearmonth = SELECTEDVALUE('Calendar'[Calendar Year Month])
var tab = 
ADDCOLUMNS(
    'Table',
    "flag",
    IF(
        ISBLANK([End Year Month]),
        IF(
            [Start Year Month]<=_yearmonth,
            1,0
        ),
        IF(
            [Start Year Month]<=_yearmonth&&
            [End Year Month]>=_yearmonth,
            1,0
        )
    )
)
return
SUMX(
    tab,
    [flag]
)

 

Finally you may put the measure in the visual level filter and use the year-month column from 'Calendar' table to filter the result.

e2.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

View solution in original post

2 REPLIES 2
v-alq-msft
Community Support
Community Support

Hi, @trt18-sistemas 

 

Based on your description, I created data to reproduce your scenario. The pbix file is attached in the end.

Table:

e1.png

 

Calendar(a calculated table):

Calendar = CALENDARAUTO()

 

You may create calculated columns and a measure as below.

Calculated column:

Calendar Year Month = YEAR('Calendar'[Date])*100+MONTH('Calendar'[Date])
Start Year Month = YEAR('Table'[Start Date])*100+MONTH('Table'[Start Date])
End Year Month = YEAR('Table'[End Date])*100+MONTH('Table'[End Date])

 

Measure:

Visual Control = 
var _yearmonth = SELECTEDVALUE('Calendar'[Calendar Year Month])
var tab = 
ADDCOLUMNS(
    'Table',
    "flag",
    IF(
        ISBLANK([End Year Month]),
        IF(
            [Start Year Month]<=_yearmonth,
            1,0
        ),
        IF(
            [Start Year Month]<=_yearmonth&&
            [End Year Month]>=_yearmonth,
            1,0
        )
    )
)
return
SUMX(
    tab,
    [flag]
)

 

Finally you may put the measure in the visual level filter and use the year-month column from 'Calendar' table to filter the result.

e2.png

 

Best Regards

Allan

 

If this post helps, then please consider Accept it as the solution to help the 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.