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
alexricker0928
Frequent Visitor

Variable in DATEADD function

I'm trying to age certain dollar amounts based on the due date of the invoice. 

I have a 'before' date filter in my report that runs the report 'as of' whatever is selected. 

 

Let's say I run the report as of 11/06/2020, I want to calculate the Balance Last 30 Days based on the date selected in the filter. I essentially want to sum the dollar amounts on all transactions that have a due date less than 11/06/2020 and greater than 10/05/2020. Here is the calculation I currently have:

 

CT Balance Last 30 Days =
VAR CurrentDate =
IF(
COUNTROWS(DISTINCT(ALLSELECTED('DimDate-InvoiceDate'[Date]))) = 1,
SELECTEDVALUE('DimDate-InvoiceDate'[Date]),
MAX('DimDate-InvoiceDate'[Date])
)

Return
CALCULATE(SUM(OpenARPrepayments[AmountMST]),
FILTER(OpenARPrepayments,
OpenARPrepayments[DueDate] < CurrentDate
&&
OpenARPrepayments[DueDate] > DATEADD(CurrentDate,-30,DAY)
)
 
 
It won't let me pass the variable into the DATEADD function, but I can't think of another way to get this to work.
 
1 ACCEPTED SOLUTION
AntrikshSharma
Community Champion
Community Champion

@alexricker0928 DATEADD is a table function and in the first argument it expects a list of dates, if for some reasons you had to go by your way you have to wrap it inside curly braces { CurrentDate }

 

try if this works:

CT Balance Last 30 Days =
VAR CurrentDate =
    SELECTEDVALUE (
        'DimDate-InvoiceDate'[Date],
        MAX ( 'DimDate-InvoiceDate'[Date] )
    )
RETURN
    CALCULATE (
        SUM ( OpenARPrepayments[AmountMST] ),
        FILTER (
            OpenARPrepayments,
            OpenARPrepayments[DueDate] < CurrentDate
                && OpenARPrepayments[DueDate] > CurrentDate - 30
        )
    )

 

View solution in original post

2 REPLIES 2
AntrikshSharma
Community Champion
Community Champion

@alexricker0928 DATEADD is a table function and in the first argument it expects a list of dates, if for some reasons you had to go by your way you have to wrap it inside curly braces { CurrentDate }

 

try if this works:

CT Balance Last 30 Days =
VAR CurrentDate =
    SELECTEDVALUE (
        'DimDate-InvoiceDate'[Date],
        MAX ( 'DimDate-InvoiceDate'[Date] )
    )
RETURN
    CALCULATE (
        SUM ( OpenARPrepayments[AmountMST] ),
        FILTER (
            OpenARPrepayments,
            OpenARPrepayments[DueDate] < CurrentDate
                && OpenARPrepayments[DueDate] > CurrentDate - 30
        )
    )

 

What if the situation requires the filter to be "CurrentDate - 1 Quarter". What can you do then? (different quarter has different number of days)

 

thank you!

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.

Top Solution Authors