I think I understand what you are wanting.
First, you stated that your table is growing. I assume you mean the table in columns A

. I made that table a
Structured Table so that ALL the formulas now use
Structured Table References, so it doesn't matter how many layers your table has. The
Structured Table default name is
Table1. No more A1 notation for table references. And BTW, your original references to those ranges were all INCORRECT!
If the last row of your table is a "Sand" Material, you must add a "Non Sand" row. My example shows such a row. Failing to do so will result in an incorrect summation.
The OFFSET() function was complicating your approach. Rather, I am using
INDEX & MATCH to locate the first/last occurrence of Material based on your X value (Sand or not).
INDEX & MATCH are used on the
First & Last layers.
The
Material Thickness calculations are using
SUMPRODUCT() rather than SUMIFS(), which in my pea brain mind, is so much easier to 1) code and 2) intuitively understand.
Total sand with in X & Y use SUMPRODUCT().
I've uploaded you workbook revised.
Here are the formulas for columns I, K & J:
[pre]
From X to 1st layer:
=IF
(
INDEX(Table1[Material],MATCH(G2,Table1[From],1),1)="Sand",
MIN(H2-G2,INDEX(Table1[to],MATCH(G2,Table1[From],1),1)-G2),
0
)
Total sand with in X & Y:
=SUMPRODUCT
(
(Table1[Thicknes (m)])*
(Table1[Material]="Sand")*
(Table1[to]<=H2)*
(Table1[From]>G2)
)
last layer available up to Y:
=IF
(
AND(
INDEX(Table1[Material],MATCH(H2,Table1[From],1),1)="Sand",
MATCH(G2,Table1[From],1)<>MATCH(H2,Table1[From],1)
),
H2-INDEX(Table1[From],MATCH(H2,Table1[From],1),1),
0
)
[/pre]
Let me know if I miss-interpreted your intentions or if you need an better explanation of what these expressions are doing.
Skip,
Just traded in my OLD subtlety...
for a NUance!![[tongue] [tongue] [tongue]](/data/assets/smilies/tongue.gif)