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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
SurendraD
Frequent Visitor

Calculated Column between two dates

I have two tables such as A and B given below. I want to calculate the Pending qty column in the B table and logic will be Calculate( Sum(Qty), A[date1] < B[Bate], A[Date2] >= B[Date] ).  FYI Sample Result Table.


I was struck to build the relationship between A and B tables. I tried some relationships also but those didn't work and sometimes the pending qty column gets blanks.



Table : A

CityDate1Date2Qty
Hyderabad1/25/20241/28/2024116
Hyderabad1/27/20241/30/2024383
Hyderabad1/29/20242/1/2024409
Delhi1/30/20242/2/2024252
Delhi1/31/20242/3/2024211
Chennai2/1/20242/4/202449
Chennai2/2/20242/5/2024128
Chennai2/3/20242/6/2024327
Chennai2/5/20242/8/2024476
Hyderabad2/6/20242/9/2024108
Hyderabad1/28/20241/31/2024190
Delhi1/30/20242/2/2024242
Hyderabad2/1/20242/4/2024350
Hyderabad2/2/20242/5/2024356
Delhi2/3/20242/6/2024197
Chennai2/4/20242/7/2024246
Hyderabad2/5/20242/8/2024152
Delhi2/6/20242/9/2024473
Chennai2/8/20242/11/2024312
Hyderabad1/27/20241/30/2024210
Delhi1/30/20242/2/2024492
Chennai2/4/20242/7/2024382
Delhi1/31/20242/3/2024392
Hyderabad2/6/20242/9/2024118


Table : B

CityDate
Hyderabad1/25/2024
Hyderabad1/27/2024
Hyderabad1/29/2024
Delhi1/30/2024
Delhi1/31/2024
Chennai2/1/2024
Chennai2/2/2024
Chennai2/3/2024
Chennai2/5/2024
Hyderabad2/6/2024
Hyderabad1/28/2024
Hyderabad2/1/2024
Hyderabad2/2/2024
Delhi2/3/2024
Chennai2/4/2024
Hyderabad2/5/2024
Delhi2/6/2024
Chennai2/8/2024





Sample Result:

CityDatePending
Hyderabad1/25/20240
Hyderabad1/27/2024116
Hyderabad1/29/2024783
Delhi1/30/20240
Delhi1/31/2024986
Chennai2/1/20240
Chennai2/2/202449
Chennai2/3/2024177
Chennai2/5/20241083
Hyderabad2/6/2024152
Hyderabad1/28/2024709
Hyderabad2/1/2024409
Hyderabad2/2/2024350
Delhi2/3/2024603
Chennai2/4/2024504
Hyderabad2/5/2024356
Delhi2/6/2024197
Chennai2/8/2024476


@power @daxdax @dax @DAXY @RelationalData @po @pros Kindly help me to fix this 

1 ACCEPTED SOLUTION
_AAndrade
Super User
Super User

Hi,

Here is my solution for your problem:

1. Create a new table with only the City to connect with the other two tables

_AAndrade_0-1711533035994.png

 

2. Use this measure: 

Sum with Cond = 
VAR _CurrDate = MAX(Table_B[Date])
VAR _Sum = 
    CALCULATE(
            SUM(Table_A[Qty]),
            FILTER(
                Table_A,
                Table_A[Date1]<_CurrDate && Table_A[Date2] >= _CurrDate
            )
    )
VAR _Result = 
SWITCH(
    TRUE(),
    NOT(ISBLANK(_CurrDate)) && _Sum=0,"-",
    NOT(ISBLANK(_CurrDate)),_Sum
)
RETURN
_Result


And on your table put this fields:
City from the new table, Date from the Table B and the Sum With Cond measure. Like this:

_AAndrade_1-1711533173483.png


The final result would be this:

_AAndrade_2-1711533197393.png

If you need any help please let me know.





Did I answer your question? Mark my post as a solution! Kudos are welcome.

Proud to be a Super User!




View solution in original post

1 REPLY 1
_AAndrade
Super User
Super User

Hi,

Here is my solution for your problem:

1. Create a new table with only the City to connect with the other two tables

_AAndrade_0-1711533035994.png

 

2. Use this measure: 

Sum with Cond = 
VAR _CurrDate = MAX(Table_B[Date])
VAR _Sum = 
    CALCULATE(
            SUM(Table_A[Qty]),
            FILTER(
                Table_A,
                Table_A[Date1]<_CurrDate && Table_A[Date2] >= _CurrDate
            )
    )
VAR _Result = 
SWITCH(
    TRUE(),
    NOT(ISBLANK(_CurrDate)) && _Sum=0,"-",
    NOT(ISBLANK(_CurrDate)),_Sum
)
RETURN
_Result


And on your table put this fields:
City from the new table, Date from the Table B and the Sum With Cond measure. Like this:

_AAndrade_1-1711533173483.png


The final result would be this:

_AAndrade_2-1711533197393.png

If you need any help please let me know.





Did I answer your question? Mark my post as a solution! Kudos are welcome.

Proud to be a Super User!




Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

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.