Dynamic Subtotal of column after each row entry has been multiplied by two-way lookup

PrettyGood_Not Great

Board Regular
Joined
Nov 24, 2023
Messages
95
Office Version
  1. 365
Platform
  1. Windows
Hi, I have a challenge to produce a column total above the header row, where the total is the sum product of the entire row, after each entry has been multiplied against the rate table. Currently showing in row A of the data table is the double XLOOKUP to find the rate.

Thanks to @Fluff for the solution in column H where this operation is being performed for the rows. The challenge here is to have the same results for the column totals, BUT it needs to produce a subtotal when filtering on the Charge Codes (column I). Anyone know a 365 solution to this?

book1.xlsm
ABCDEFGHIJKLMNOPQRSTUVWXY
1Subtotal-->192.5192.5192.5192.5192.5192.5192.5192.5192.5192.5192.5192.5198.3198.3198.3
2RateCode20232024202520262027SUM ResultCharge CodeSkill/RateJan-24Feb-24Mar-24Apr-24May-24Jun-24Jul-24Aug-24Sep-24Oct-24Nov-24Dec-24Jan-25Feb-25Mar-25
3R1186.9192.5198.3204.2210.3269685.2A101A1R1108120150114114138757590717575687547
4R2131.9135.9139.9144.1148.5186573.3A102B1R281120150114114138757590717575687547
5R3106.0109.2112.4115.8119.373516.2A103C1R3414556434352454554434545414528
6R482.184.587.189.792.490737.4A104D1R468759471718675759071757568750
7R547.348.750.151.653.247005.4A105E1R561688464647868688164686861680
Sheet1
Cell Formulas
RangeFormula
K1:Y1K1=XLOOKUP(RIGHT($J3,2),$A$3:$A$7,XLOOKUP(YEAR(K$2),$B$2:$F$2,$B$3:$F$7))
H3:H7H3=SUM(MAP($K$2:$Y$2,K3:Y3,LAMBDA(a,b,b*XLOOKUP(RIGHT($J3,2),$A$3:$A$7,XLOOKUP(YEAR(a),$B$2:$F$2,$B$3:$F$7)))))
 
Last edited by a moderator:
I doubt the spilled range reference is the problem. Can you post the version of the formula you are using (overwrite the sheet name with something generic if it is sensitive), but try to duplicate as closely as possible what your formula looks like.

Some behind-the-scenes diagnostics might help. Go the the cell with the issue, and in the formula bar, use the cursor selection to highlight this part of the formula:
Excel Formula:
FILTER($P4:$P8,MAP($P$4:$P$8,LAMBDA(r,--(SUBTOTAL(103,r)=1))))
...and then hover the cursor over that highlighting to see a preview of what the returned array looks like, or alternatively, hit F9 to insert that array directly into your formula for closer examination (But do not hit Enter because you don't want to permanently commit/hardwire this array into the formula). Does it appear to be correct? You should see a trimmed down array showing only the visible Charge Codes in the P columns...those that are to be considered in the lookup table. Then hit Esc to revert back to your original formula.

Next, repeat the highlight/selection steps to investigate the array returned by:
Excel Formula:
ISNUMBER(MATCH($B$4:$B$8,FILTER($P4:$P8,MAP($P$4:$P$8,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0))
You should see an array of TRUE/FALSE and it should reflect which rows in the lookup table have Charge Codes of interest...and any FALSE's should correspond to Charge Codes that are filtered out.

Repeat the examination of:
Excel Formula:
($K$4:$K$8=R$3)
...does the Primary Criteria array appear to be correct? Any FALSE's should correspond to rows that do not meet the match criteria.

And does
Excel Formula:
($N$4:$N$8)
have all numeric values, or is there text or something else non-numeric somewhere in that range?
 
Upvote 0

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN
I doubt the spilled range reference is the problem. Can you post the version of the formula you are using (overwrite the sheet name with something generic if it is sensitive), but try to duplicate as closely as possible what your formula looks like.

Some behind-the-scenes diagnostics might help. Go the the cell with the issue, and in the formula bar, use the cursor selection to highlight this part of the formula:
Excel Formula:
FILTER($P4:$P8,MAP($P$4:$P$8,LAMBDA(r,--(SUBTOTAL(103,r)=1))))
...and then hover the cursor over that highlighting to see a preview of what the returned array looks like, or alternatively, hit F9 to insert that array directly into your formula for closer examination (But do not hit Enter because you don't want to permanently commit/hardwire this array into the formula). Does it appear to be correct? You should see a trimmed down array showing only the visible Charge Codes in the P columns...those that are to be considered in the lookup table. Then hit Esc to revert back to your original formula.

Next, repeat the highlight/selection steps to investigate the array returned by:
Excel Formula:
ISNUMBER(MATCH($B$4:$B$8,FILTER($P4:$P8,MAP($P$4:$P$8,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0))
You should see an array of TRUE/FALSE and it should reflect which rows in the lookup table have Charge Codes of interest...and any FALSE's should correspond to Charge Codes that are filtered out.

Repeat the examination of:
Excel Formula:
($K$4:$K$8=R$3)
...does the Primary Criteria array appear to be correct? Any FALSE's should correspond to rows that do not meet the match criteria.

And does
Excel Formula:
($N$4:$N$8)
have all numeric values, or is there text or something else non-numeric somewhere in that range?
Here is the actual sheet in question. The equation is in cell M8. I am looking into the details as well
EDIT
Removed as contain sensitive data.
 
Last edited by a moderator:
Upvote 0
Note that the three major terms (arrays to be multiplied) in the SUM function should have the same dimensions…yours do not.
 
Upvote 0
I doubt the spilled range reference is the problem. Can you post the version of the formula you are using (overwrite the sheet name with something generic if it is sensitive), but try to duplicate as closely as possible what your formula looks like.

Some behind-the-scenes diagnostics might help. Go the the cell with the issue, and in the formula bar, use the cursor selection to highlight this part of the formula:
Excel Formula:
FILTER($P4:$P8,MAP($P$4:$P$8,LAMBDA(r,--(SUBTOTAL(103,r)=1))))
...and then hover the cursor over that highlighting to see a preview of what the returned array looks like, or alternatively, hit F9 to insert that array directly into your formula for closer examination (But do not hit Enter because you don't want to permanently commit/hardwire this array into the formula). Does it appear to be correct? You should see a trimmed down array showing only the visible Charge Codes in the P columns...those that are to be considered in the lookup table. Then hit Esc to revert back to your original formula.

Next, repeat the highlight/selection steps to investigate the array returned by:
Excel Formula:
ISNUMBER(MATCH($B$4:$B$8,FILTER($P4:$P8,MAP($P$4:$P$8,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0))
You should see an array of TRUE/FALSE and it should reflect which rows in the lookup table have Charge Codes of interest...and any FALSE's should correspond to Charge Codes that are filtered out.

Repeat the examination of:
Excel Formula:
($K$4:$K$8=R$3)
...does the Primary Criteria array appear to be correct? Any FALSE's should correspond to rows that do not meet the match criteria.

And does
Excel Formula:
($N$4:$N$8)
have all numeric values, or is there text or something else non-numeric somewhere in that range?
So for some reason after using cursor to select the portions of equations via formula bar, when I hover over the selection nothing appears. So I used the error checking to show calculation steps. For the SUM it's all long string of zeros followed by a long string of #N/As. For the ISNUBMER(MATCH() all of the charge codes are being returned.

N4:N8 is either a positive value or zeros. I can't get a read on K4:K8.
 
Upvote 0
Note that the three major terms (arrays to be multiplied) in the SUM function should have the same dimensions…yours do not.
They did when I started, excel changed this when I selected Include Cell references. I have changed it back a couple times and no effect
 
Upvote 0
The #N/A’s are probably due to the dimensional mismatch I mentioned. You’re multiplying a 13000+ row array by other arrays that are only about 1300 rows long.
 
Upvote 0
It can be tricky sometimes to highlight the correct part of a formula. Usually, for me, the problem occurs when I don’t get the matched parentheses selections just right. And hovering sometimes doesn’t work if the cursor strays too far from the selection. Hit F9 in those cases…but be sure to hit Esc when you’re done looking.
 
Upvote 0
The #N/A’s are probably due to the dimensional mismatch I mentioned. You’re multiplying a 13000+ row array by other arrays that are only about 1300 rows long.
I think your right about that, but i can't confirm. once I changed the range back to 1300 the "show calculation step" option disappeared. This is what the error box is providing for options, if this is of any help.

1704306230016.png
 
Upvote 0
Those types of error messages are often not really errors. Excel tends to flag cells with green triangles suggesting that maybe there is an error if it seems as if a formula should be extended down a column or across a row.

Do you think that cell might factor into the problem? I can’t tell where that cell is located on the worksheet.
 
Upvote 0
It can be tricky sometimes to highlight the correct part of a formula. Usually, for me, the problem occurs when I don’t get the matched parentheses selections just right. And hovering sometimes doesn’t work if the cursor strays too far from the selection. Hit F9 in those cases…but be sure to hit Esc when you’re done looking.
ok i'm with you now.

For Filter - all results are TRUE.

For ISNUMBER I am getting all the charge codes, plus some zeros at the end (screen shot below)
1704306613137.png


I think the problem is here: ($K$4:$K$8=R$3) as all results are FALSE
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,849
Members
452,361
Latest member
d3ad3y3

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top