Share feedback directly with Fabric product managers, participate in targeted research studies and influence the Fabric roadmap.
Sign up nowGet Fabric certified for FREE! Don't miss your chance! Learn more
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
| City | Date1 | Date2 | Qty |
| Hyderabad | 1/25/2024 | 1/28/2024 | 116 |
| Hyderabad | 1/27/2024 | 1/30/2024 | 383 |
| Hyderabad | 1/29/2024 | 2/1/2024 | 409 |
| Delhi | 1/30/2024 | 2/2/2024 | 252 |
| Delhi | 1/31/2024 | 2/3/2024 | 211 |
| Chennai | 2/1/2024 | 2/4/2024 | 49 |
| Chennai | 2/2/2024 | 2/5/2024 | 128 |
| Chennai | 2/3/2024 | 2/6/2024 | 327 |
| Chennai | 2/5/2024 | 2/8/2024 | 476 |
| Hyderabad | 2/6/2024 | 2/9/2024 | 108 |
| Hyderabad | 1/28/2024 | 1/31/2024 | 190 |
| Delhi | 1/30/2024 | 2/2/2024 | 242 |
| Hyderabad | 2/1/2024 | 2/4/2024 | 350 |
| Hyderabad | 2/2/2024 | 2/5/2024 | 356 |
| Delhi | 2/3/2024 | 2/6/2024 | 197 |
| Chennai | 2/4/2024 | 2/7/2024 | 246 |
| Hyderabad | 2/5/2024 | 2/8/2024 | 152 |
| Delhi | 2/6/2024 | 2/9/2024 | 473 |
| Chennai | 2/8/2024 | 2/11/2024 | 312 |
| Hyderabad | 1/27/2024 | 1/30/2024 | 210 |
| Delhi | 1/30/2024 | 2/2/2024 | 492 |
| Chennai | 2/4/2024 | 2/7/2024 | 382 |
| Delhi | 1/31/2024 | 2/3/2024 | 392 |
| Hyderabad | 2/6/2024 | 2/9/2024 | 118 |
Table : B
| City | Date |
| Hyderabad | 1/25/2024 |
| Hyderabad | 1/27/2024 |
| Hyderabad | 1/29/2024 |
| Delhi | 1/30/2024 |
| Delhi | 1/31/2024 |
| Chennai | 2/1/2024 |
| Chennai | 2/2/2024 |
| Chennai | 2/3/2024 |
| Chennai | 2/5/2024 |
| Hyderabad | 2/6/2024 |
| Hyderabad | 1/28/2024 |
| Hyderabad | 2/1/2024 |
| Hyderabad | 2/2/2024 |
| Delhi | 2/3/2024 |
| Chennai | 2/4/2024 |
| Hyderabad | 2/5/2024 |
| Delhi | 2/6/2024 |
| Chennai | 2/8/2024 |
Sample Result:
| City | Date | Pending |
| Hyderabad | 1/25/2024 | 0 |
| Hyderabad | 1/27/2024 | 116 |
| Hyderabad | 1/29/2024 | 783 |
| Delhi | 1/30/2024 | 0 |
| Delhi | 1/31/2024 | 986 |
| Chennai | 2/1/2024 | 0 |
| Chennai | 2/2/2024 | 49 |
| Chennai | 2/3/2024 | 177 |
| Chennai | 2/5/2024 | 1083 |
| Hyderabad | 2/6/2024 | 152 |
| Hyderabad | 1/28/2024 | 709 |
| Hyderabad | 2/1/2024 | 409 |
| Hyderabad | 2/2/2024 | 350 |
| Delhi | 2/3/2024 | 603 |
| Chennai | 2/4/2024 | 504 |
| Hyderabad | 2/5/2024 | 356 |
| Delhi | 2/6/2024 | 197 |
| Chennai | 2/8/2024 | 476 |
@power @daxdax @dax @DAXY @RelationalData @po @pros Kindly help me to fix this
Solved! Go to Solution.
Hi,
Here is my solution for your problem:
1. Create a new table with only the City to connect with the other two tables
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:
The final result would be this:
If you need any help please let me know.
Proud to be a 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
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:
The final result would be this:
If you need any help please let me know.
Proud to be a Super User!
If you love stickers, then you will definitely want to check out our Community Sticker Challenge!
Check out the January 2026 Power BI update to learn about new features.
| User | Count |
|---|---|
| 64 | |
| 63 | |
| 48 | |
| 21 | |
| 18 |
| User | Count |
|---|---|
| 118 | |
| 117 | |
| 38 | |
| 36 | |
| 27 |