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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
Anonymous
Not applicable

Sum values of given period with DATESBETWEEN

Hi. I have the following 2 tables:

Table 1 - breakdown of daily value

IDevent-timeValue
11-Jan-211.5
12-Jan-211.8
14-Jan-219.0
16-Jan-2132.2
17-Jan-213.4
18-Jan-2111.0
19-Jan-218.0
113-Jan-2114.0
114-Jan-219.0
115-Jan-211.0
27-Jan-216.0
28-Jan-215.0
29-Jan-2110.0
210-Jan-2113.0
211-Jan-212.0

 

Table 2: overview with event ID

IDevent IDstart-dateend-dateDesired Output
11.131-Dec-204-Jan-2112.3
11.25-Jan-2110-Jan-2154.6
11.312-Jan-2117-Jan-2124
22.16-Jan-2112-Jan-2136

 

Essentially I have a master table (table 2) with ID, event IDs, end and start dates. I would ideally like to "sumif" table 1 if ID matches, and if the event-time is => start-date, and =< end-date. 

However, I am having issues creating a measure for it. I tried the below but it shows an error:

 

 

DesiredOutput = CALCULATE (SUM(Table1[Value]), Table1[ID], Table2[event ID], DATESBETWEEN (Table1[event-time], MAX(Table2[start-date]), MAX(Table2[end-date])))

 

 

 

 

 

MdxScript(Model)(35,173)Calculation error in measure 'Table2[DesiredOutput]': A date column containing duplicate dates was specified in the call to function 'DATESBETWEEN'. This is not supported. 

 

 

2 ACCEPTED SOLUTIONS
CNENFRNL
Community Champion
Community Champion

DesiredOutput = 
CALCULATE(
    SUM( BREAKDOWN[Value] ),
    FILTER( BREAKDOWN, BREAKDOWN[ID] = OVERVIEW[ID] ),
    DATESBETWEEN( BREAKDOWN[event-time], OVERVIEW[start-date], OVERVIEW[end-date] )
)

Screenshot 2021-06-29 172252.png

 

I prefer

TOTAL = 
VAR __id = OVERVIEW[ID]
VAR __start = OVERVIEW[start-date]
VAR __end = OVERVIEW[end-date]
RETURN
    SUMX(
        FILTER(
            BREAKDOWN,
            BREAKDOWN[ID] = __id
                && BREAKDOWN[event-time] >= __start
                && BREAKDOWN[event-time] <= __end
        ),
        BREAKDOWN[Value]
    )

Screenshot 2021-06-29 173834.png

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

View solution in original post

Anonymous
Not applicable

@CNENFRNL thank you so much for the above. The file that you sent over works.

 

I tried to replicate on my end but I have this error "A single value for column 'ID' in table 'OVERVIEW' cannot be determined. THis can happen when a measure formula refers to a column that contains many values without specifiying an aggregation such as min, max, count, or sum to get a single result."

View solution in original post

4 REPLIES 4
Anonymous
Not applicable

@CNENFRNL 

 

I had changed all the data types similarly to how you had them. 


Only difference here is that I had to add max() when defining the variables for it to be working for me. Might the difference in syntax be due to the different PowerBI desktop versions?

TOTAL = 
VAR __id = MAX(OVERVIEW[ID])
VAR __start = MAX(OVERVIEW[start-date])
VAR __end = MAX(OVERVIEW[end-date])

 

 

Anonymous
Not applicable

@CNENFRNL thank you so much for the above. The file that you sent over works.

 

I tried to replicate on my end but I have this error "A single value for column 'ID' in table 'OVERVIEW' cannot be determined. THis can happen when a measure formula refers to a column that contains many values without specifiying an aggregation such as min, max, count, or sum to get a single result."

CNENFRNL
Community Champion
Community Champion

DesiredOutput = 
CALCULATE(
    SUM( BREAKDOWN[Value] ),
    FILTER( BREAKDOWN, BREAKDOWN[ID] = OVERVIEW[ID] ),
    DATESBETWEEN( BREAKDOWN[event-time], OVERVIEW[start-date], OVERVIEW[end-date] )
)

Screenshot 2021-06-29 172252.png

 

I prefer

TOTAL = 
VAR __id = OVERVIEW[ID]
VAR __start = OVERVIEW[start-date]
VAR __end = OVERVIEW[end-date]
RETURN
    SUMX(
        FILTER(
            BREAKDOWN,
            BREAKDOWN[ID] = __id
                && BREAKDOWN[event-time] >= __start
                && BREAKDOWN[event-time] <= __end
        ),
        BREAKDOWN[Value]
    )

Screenshot 2021-06-29 173834.png

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Anonymous
Not applicable

I now have a new requirement. I have successfully managed to obtained the "TOTAL". However, I have to multiply them by a factor specific to its category.  I suspect that this is a SUMPRODUCT problem but have yet to modify the previous solution provided to achieve it. 

OVERALL:

IDevent IDstart-dateend-date
11.12020-12-312021-01-04
11.22021-01-052021-01-10
11.32021-01-122021-01-17
22.12021-01-062021-01-12


BREAKDOWN: the difference between this breakdown table and previously mentioned, is that the "Value" column is further broken down by category

 

IDevent-timesub-categoryValue
12020-01-01A0.5
12020-01-01B0.2
12020-01-01C0.8
12020-01-02A0.9
12020-01-02B0.3
12020-01-02C0.6

 

Multiplication factor

sub-categorymultiplication factor
A1.7
B

1.2

C

1.9


Appreciate any help on this

@CNENFRNL 

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 2025 Power BI update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.