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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
Roberto456
Resolver I
Resolver I

Cant filter with 2 conditions

Hello everyone.

 

Im having a  weird problem with something.

 

Im trying to filter my report for sales up until the last invoice this month compared to same period last month.

 

Below is my formula:

 

Latest Invoice = CALCULATE(MAX('(Fact) Cart'[Invoice_Date]))

 

Test 2 =
VAR LATESTMONTH = CALCULATE(MAX('(Dim) Calendar'[Rolling Month #]),ALL('(Dim) Calendar'))
VAR STARTDATE = DATE(YEAR([Latest Invoice]),MONTH([Latest Invoice])-1,1)
VAR ENDDATE = DATE(YEAR([Latest Invoice]),MONTH([Latest Invoice])-1,DAY([Latest Invoice]))
RETURN
IF(MAX('(Dim) Calendar'[Rolling Month #]) = LATESTMONTH,
CALCULATE([Metric],FILTER(ALL('(Dim) Calendar'),'(Dim) Calendar'[Date] >= STARTDATE && '(Dim) Calendar'[Date] <= ENDDATE)),
CALCULATE([Metric],FILTER(ALL('(Dim) Calendar'),'(Dim) Calendar'[Rolling Month #] = MAX('(Dim) Calendar'[Rolling Month #])-1)))
 
i get this error when putting the measure in with any another field, (it works by itself though). 
It also only works when i put in a calendar field from the dimension table, but that is it.
error.JPG
 
 
If I remove the RED text it will work, but if i leave it in it causes the above error. 
There is something to do with having 2 conditons that is causing this error
 
The goal is to put this in with products but it wont work, anyone know why?
 

 

 

1 ACCEPTED SOLUTION

Hi @Roberto456 ,

This error message may be caused by the value of the day part of the obtained end date being too large. For example, assume that LATESTMONTH you obtained is 2020/3/31, then STARTDATE is 2020/2/1 and ENDDATE is equal to 2020/2/31 based on your original formula. However, February 2020 can only have 28 days at most, but what you get is 31, which does not conform to the date format. Thus an error was reported. Please update the formula of measure Test 2 as below:

Test 2 =
VAR LATESTMONTH = CALCULATE(MAX('(Dim) Calendar'[Rolling Month #]),ALL('(Dim) Calendar'))
VAR STARTDATE = DATE(YEAR([Latest Invoice]),MONTH([Latest Invoice])-1,1)
VAR ENDDATE = EOMONTH(STARTDATE ,0)
RETURN
IF(MAX('(Dim) Calendar'[Rolling Month #]) = LATESTMONTH,
CALCULATE([Metric],FILTER(ALL('(Dim) Calendar'),'(Dim) Calendar'[Date] >= STARTDATE && '(Dim) Calendar'[Date] <= ENDDATE)),
CALCULATE([Metric],FILTER(ALL('(Dim) Calendar'),'(Dim) Calendar'[Rolling Month #] = MAX('(Dim) Calendar'[Rolling Month #])-1)))

Best Regards

Rena

Community Support Team _ Rena
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

3 REPLIES 3
Roberto456
Resolver I
Resolver I

so i figured out the root cause of the problem and its,

 

VAR ENDDATE = DATE(YEAR([Latest Invoice]),MONTH([Latest Invoice])-1,DAY([Latest Invoice]))

 

if i put and integer in there it will work,

 

why would DAY() be causing this issue?

 

EDIT:

 

if i replaced DAY([Latest Invoice]) from the fact table to MAX invoice DAte from the Dimension table, it works, but it wont work with filters now...

Hi @Roberto456 ,

This error message may be caused by the value of the day part of the obtained end date being too large. For example, assume that LATESTMONTH you obtained is 2020/3/31, then STARTDATE is 2020/2/1 and ENDDATE is equal to 2020/2/31 based on your original formula. However, February 2020 can only have 28 days at most, but what you get is 31, which does not conform to the date format. Thus an error was reported. Please update the formula of measure Test 2 as below:

Test 2 =
VAR LATESTMONTH = CALCULATE(MAX('(Dim) Calendar'[Rolling Month #]),ALL('(Dim) Calendar'))
VAR STARTDATE = DATE(YEAR([Latest Invoice]),MONTH([Latest Invoice])-1,1)
VAR ENDDATE = EOMONTH(STARTDATE ,0)
RETURN
IF(MAX('(Dim) Calendar'[Rolling Month #]) = LATESTMONTH,
CALCULATE([Metric],FILTER(ALL('(Dim) Calendar'),'(Dim) Calendar'[Date] >= STARTDATE && '(Dim) Calendar'[Date] <= ENDDATE)),
CALCULATE([Metric],FILTER(ALL('(Dim) Calendar'),'(Dim) Calendar'[Rolling Month #] = MAX('(Dim) Calendar'[Rolling Month #])-1)))

Best Regards

Rena

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

woo it works 🙂

 

Test =
VAR LATESTMONTH = CALCULATE(MAX('(Dim) Calendar'[Rolling Month #]),ALL('(Dim) Calendar'))
VAR STARTDATE = DATE(YEAR([Latest Invoice]),MONTH([Latest Invoice]),1)
VAR ENDDATE = DATE(YEAR([Latest Invoice]),MONTH([Latest Invoice]),EOMONTH(STARTDATE ,0))
RETURN
IF(MAX('(Dim) Calendar'[Rolling Month #]) = LATESTMONTH,
CALCULATE([Metric],FILTER(ALL('(Dim) Calendar'),'(Dim) Calendar'[Date] >= STARTDATE && '(Dim) Calendar'[Date] <= ENDDATE)),
CALCULATE([Metric PM]))

 

 

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.