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:
For clarity,

book1.xlsm
ABCDEFGHIJK
1192.4864192.4864192.4864192.4864192.4864
2Primary CriteriaCharge CodeHourCharge CodeSkill/RateAABBCCDDEE
3AAA101192.5A101A1R1108120150114114
4BBA102135.9A102B1R281120150114114
5CCA103109.2A103C1R34145564343
6DDA10484.5A104D1R46875947171
7EEA10548.7A105E1R56168846464
Sheet1
Cell Formulas
RangeFormula
G1:K1G1=SUMIFS($C:$C,$A:$A,$G$2,$B:$B,$E$3)
 
Last edited by a moderator:
Upvote 0

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
Thanks for the clarification. I followed the ISNUMBER error trap implementation just fine, but I was confused when you mentioned in post #5, "...may not be handling blank returns on column J". The ISNUMBER function operates on "b", which is the array passed into MAP---and in this case "b" refers to the data block column K, L, etc. as the formula is copied across. A blank on column J (Skill/Rate code) induces a different type of error (#N/A), not a #VALUE error. But I haven't been able to reproduce the #VALUE error with blanks. However, a text value in the data block (col K and to the right) will induce a #VALUE error, and the ISNUMBER error trap will then handle it correctly. Do you occasionally have text in column K and to the right?

About this adaptation to the SUMIFS formula, I'm confused by the $B:$B,$E$3 portion. Do you want to sum all values in column C where two conditions are met:
  1. all date rows in the left-side table that match the subject column heading in the right-side table (e.g., A:A=G2) AND...
  2. all Charge Codes in B:B that match any visible charge code in E:E (i.e., a Charge Code that has not been hidden with a filter)? Your example formula includes $E$3, which is leading to this confusion/question.
 
Upvote 0
Thanks for the clarification. I followed the ISNUMBER error trap implementation just fine, but I was confused when you mentioned in post #5, "...may not be handling blank returns on column J". The ISNUMBER function operates on "b", which is the array passed into MAP---and in this case "b" refers to the data block column K, L, etc. as the formula is copied across. A blank on column J (Skill/Rate code) induces a different type of error (#N/A), not a #VALUE error. But I haven't been able to reproduce the #VALUE error with blanks. However, a text value in the data block (col K and to the right) will induce a #VALUE error, and the ISNUMBER error trap will then handle it correctly. Do you occasionally have text in column K and to the right?

About this adaptation to the SUMIFS formula, I'm confused by the $B:$B,$E$3 portion. Do you want to sum all values in column C where two conditions are met:
  1. all date rows in the left-side table that match the subject column heading in the right-side table (e.g., A:A=G2) AND...
  2. all Charge Codes in B:B that match any visible charge code in E:E (i.e., a Charge Code that has not been hidden with a filter)? Your example formula includes $E$3, which is leading to this confusion/question.

ok nice, thanks for the breakdown, really helpful. For the col K, when it's dates they are a dynamic spilled range, but on other sheets it can also be text, as in the latest example.

For the adaption to SUMIFS - yes correct. one condition will be the header row of the active sheet, and the other condition will be listed vertically along side to the left.
1. Correct
2. I see your confusion, my apologies. $E$3 was used incorrectly to identify the criteria range, It should read E3:Ex.
 
Upvote 0
Okay...I think I understand. Give this a try...and test carefully. You define two ranges in the formula: 1) the range of the Charge Code in the right-hand table (I've called this column ccr), and 2) the range of the lookup table from which the values to be summed come from (I've named this array ary). The MAP(ccr,LAMBDA(r,--(SUBTOTAL(103,r)=1))) component relies on SUBTOTAL's ability to distinguish whether a row has been hidden with a filter. So this creates an array of 1's and 0's indicating which Charge Codes in the right-hand table can be seen. And this array is fed into FILTER to return a consolidated array (no blanks or 0's) of only those charge codes of interest (due to the Date>Filter). That array of charge codes of interest is used by the MATCH function to determine which Charge Codes in the left-hand table (in ary) should be considered, as MATCH used like this will return a number (indicating that array element does match) or an error (indicating that array element does not match). And the MATCH results are processed by the ISERROR function within FILTER to generate a new filtered array (called fary) based on ary, except only the relevant rows of ary will be included (meaning only those rows whose Charge Codes can be found in the trimmed down/filtered list of the right-hand table). So the fary array is still a three-column array (date, charge code, and hour). And fary has already been filtered to eliminate any charge codes that should not be considered, so we then need to identify which rows satisfy the date criterion...and finally sum the corresponding hours. This is done in the last step of the formula by FILTER wrapped by SUM.

MrExcel_20231231.xlsx
ABCDEFGHIJK
1626.1135.9358.384.5 
2DateCharge CodeHourCharge CodeSkill/RateJan-24Feb-24Mar-24Apr-24May-24
3Jan-24A101192.5A101A1R1108120150114114
4Feb-24A102135.9A102B1R281120150114114
5Mar-24A103109.2A103C1R34145564343
6Apr-24A10484.5A104D1R46875947171
7Jan-24A10548.7A105E1R56168846464
8Jan-24A101192.5
9Mar-24A103109.2
10Jan-24A101192.5
11Mar-24A104140.0
Sheet6
Cell Formulas
RangeFormula
G1:K1G1=LET(ccr,$E$3:$E$7,ary,$A$3:$C$11,fary,FILTER(ary,ISERROR(MATCH(INDEX(ary,,2),FILTER(ccr,MAP(ccr,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0))=FALSE),IFERROR(SUM(FILTER(INDEX(fary,,3),(INDEX(fary,,1)=G$2))),""))
 
Upvote 0
I had another idea...have a look at the shorter row 1 formula, where there are three main terms in the SUM formula. The first specifies the C column (hours) to be added subject to certain conditions, the second requires the date criterion to be met, and the third establishes a TRUE/FALSE array indicating whether the Charge Code in column B is found in the visible filtered column E of the other table.
MrExcel_20231231.xlsx
EFGHIJK
1626.10.0140.084.50.0
2626.1 140.084.5 
3Charge CodeSkill/RateJan-24Feb-24Mar-24Apr-24May-24
4A101A1R1108120150114114
7A104D1R46875947171
8A105E1R56168846464
Sheet6
Cell Formulas
RangeFormula
G1:K1G1=SUM(($C$11:$C$19)*($A$11:$A$19=G$3)*ISNUMBER(MATCH($B$11:$B$19,FILTER($E4:$E8,MAP(G4:G8,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0)))
G2:K2G2=LET(ccr,$E$4:$E$8,ary,$A$11:$C$19,fary,FILTER(ary,ISERROR(MATCH(INDEX(ary,,2),FILTER(ccr,MAP(ccr,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0))=FALSE),IFERROR(SUM(FILTER(INDEX(fary,,3),(INDEX(fary,,1)=G$3))),""))

I moved the left-hand table for testing purposes so that all of its rows would be visible when the right-hand table filter is applied.
MrExcel_20231231.xlsx
ABC
10DateCharge CodeHour
11Jan-24A101192.5
12Feb-24A102135.9
13Mar-24A103109.2
14Apr-24A10484.5
15Jan-24A10548.7
16Jan-24A101192.5
17Mar-24A103109.2
18Jan-24A101192.5
19Mar-24A104140.0
Sheet6
 
Upvote 0
Okay...I think I understand. Give this a try...and test carefully. You define two ranges in the formula: 1) the range of the Charge Code in the right-hand table (I've called this column ccr), and 2) the range of the lookup table from which the values to be summed come from (I've named this array ary). The MAP(ccr,LAMBDA(r,--(SUBTOTAL(103,r)=1))) component relies on SUBTOTAL's ability to distinguish whether a row has been hidden with a filter. So this creates an array of 1's and 0's indicating which Charge Codes in the right-hand table can be seen. And this array is fed into FILTER to return a consolidated array (no blanks or 0's) of only those charge codes of interest (due to the Date>Filter). That array of charge codes of interest is used by the MATCH function to determine which Charge Codes in the left-hand table (in ary) should be considered, as MATCH used like this will return a number (indicating that array element does match) or an error (indicating that array element does not match). And the MATCH results are processed by the ISERROR function within FILTER to generate a new filtered array (called fary) based on ary, except only the relevant rows of ary will be included (meaning only those rows whose Charge Codes can be found in the trimmed down/filtered list of the right-hand table). So the fary array is still a three-column array (date, charge code, and hour). And fary has already been filtered to eliminate any charge codes that should not be considered, so we then need to identify which rows satisfy the date criterion...and finally sum the corresponding hours. This is done in the last step of the formula by FILTER wrapped by SUM.

MrExcel_20231231.xlsx
ABCDEFGHIJK
1626.1135.9358.384.5 
2DateCharge CodeHourCharge CodeSkill/RateJan-24Feb-24Mar-24Apr-24May-24
3Jan-24A101192.5A101A1R1108120150114114
4Feb-24A102135.9A102B1R281120150114114
5Mar-24A103109.2A103C1R34145564343
6Apr-24A10484.5A104D1R46875947171
7Jan-24A10548.7A105E1R56168846464
8Jan-24A101192.5
9Mar-24A103109.2
10Jan-24A101192.5
11Mar-24A104140.0
Sheet6
Cell Formulas
RangeFormula
G1:K1G1=LET(ccr,$E$3:$E$7,ary,$A$3:$C$11,fary,FILTER(ary,ISERROR(MATCH(INDEX(ary,,2),FILTER(ccr,MAP(ccr,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0))=FALSE),IFERROR(SUM(FILTER(INDEX(fary,,3),(INDEX(fary,,1)=G$2))),""))

Hey, so you defiantly understand correctly! The first solution presented works as I intended when I applied it to the mini sheet example. When I reference the actual data sheet (ary), I get an error (blank), this is also true if I change the order of any of the three columns in ary (per mini sheet). I can see that there are some column references indicated by numbers (1,2,3) for the reference data, and I tried adjusting these to match the new column positions of ary, but it didn't solve the issue. Below I have included the same mini sheet, but this time with the actual relative positions of our reference data as it resides on the data sheet (didn't think about that). The data sheet starts at column A and goes to S, with the last data column of interest being the hours in column N. An although it doesn't seem to be the issue for the mini sheet, when referencing the data sheet we need to do a full column reference (N:N) as this sheet grows in size every month.

For the second solution - I was not able to get it to work. In this mini sheet example, or the previous example (exact same column references you used). It is returning a "0". When I applied it to the operational sheet it returned a #VALUE. This second solution I feel is going to be the winner as all the referencing to the data sheet are clear and of a conventional manner to what most excel users will be familiar with.

Hopefully I am not wasting your time with incorrect reference, but I tried a couple times. Also, I inspected all the number formatting to make sure it was all set to General incase that could be a factor.

Note on the #VALUE for the second equation. The operational sheet uses a spilled array for charge codes (column P in mini sheet), and a spilled TRANSPOSE for the header column (which is now "Primary Criteria" in mini sheet). Not sure if this makes a difference.

Canadarm3 Labour_Planning_O365_v1.4.5.xlsm
ABCDEFGHIJKLMNOPQRSTUV
100000
2     
3x1Charge Codex2x3x4x5x6x7x8x9Primary Criteriax10x11HourCharge CodeSkill/RateAABBCCDDEE
4A101AA192.5A101A1R1108120150114114
5A102BB135.9A102B1R281120150114114
6A103CC109.2A103C1R34145564343
7A104DD84.5A104D1R46875947171
8A105EE48.7A105E1R56168846464
Sheet1
Cell Formulas
RangeFormula
R1:V1R1=SUM(($N$4:$N$8)*($K$4:$K$8=R$3)*ISNUMBER(MATCH($B$4:$B$8,FILTER($F4:$F8,MAP(H4:H8,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0)))
R2:V2R2=LET(ccr,$P$4:$P$8,ary,$B$4:$N$8,fary,FILTER(ary,ISERROR(MATCH(INDEX(ary,,2),FILTER(ccr,MAP(ccr,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0))=FALSE),IFERROR(SUM(FILTER(INDEX(fary,,3),(INDEX(fary,,1)=R$3))),""))
 
Upvote 0
For the top row version, which I think is the simplest and probably preferred, give this a try:
Excel Formula:
=SUM(($N$4:$N$8)*($K$4:$K$8=R$3)*ISNUMBER(MATCH($B$4:$B$8,FILTER($P4:$P8,MAP($P$4:$P$8,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0)))
The issue when you adapted the formula to your file involved the FILTER/MAP part of the formula. Recall the MAP portion needs to look down some column to "count" which rows are present...so it needs to see content to be counted, and it relies on the SUBTOTAL function, which will ignore rows that are hidden (including those that are not visible due to a filter). So MAP in this revision is looking at your righthand table's Charge Code column. Depending on whether cells in the range P4:P8 have something in them (1's) or not (0's) dictates what the array looks like from the MAP function...and that array is then used to create a trimmed down list (an array) of the valid Charge Codes (in column P) that need to be considered when looking at the lefthand table...so the FILTER function needs to specify the P4:P8 range. Note that it is not critical that the MAP function refer to the P4:P8 range--this is somewhat arbitrary. Previously, I had MAP looking straight below and referencing cells in the righthand table in that same column, but it might be easier to follow the formula by always pointing to the Charge Code column.
 
Upvote 0
And for the row 2 option, which is unnecessarily complicated:
Excel Formula:
=LET(ccr,$P$4:$P$8,ary,$A$4:$N$8,fary,FILTER(ary,ISERROR(MATCH(INDEX(ary,,2),FILTER(ccr,MAP(ccr,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0))=FALSE),IFERROR(SUM(FILTER(INDEX(fary,,14),(INDEX(fary,,11)=R$3))),""))
Note that I changed the ary reference to cover columns A:N (somewhat arbitrary, but it makes it convenient to count columns from the leftmost column A when setting the other column index numbers). Then the column index numbers were adjusted to point to the correct columns in the main and filtered arrays---in ary and fary---so you;ll see columns 2, 11, and 14 (charge code, primary criteria, and hour, respectively).
 
Upvote 0
For the top row version, which I think is the simplest and probably preferred, give this a try:
Excel Formula:
=SUM(($N$4:$N$8)*($K$4:$K$8=R$3)*ISNUMBER(MATCH($B$4:$B$8,FILTER($P4:$P8,MAP($P$4:$P$8,LAMBDA(r,--(SUBTOTAL(103,r)=1)))),0)))
The issue when you adapted the formula to your file involved the FILTER/MAP part of the formula. Recall the MAP portion needs to look down some column to "count" which rows are present...so it needs to see content to be counted, and it relies on the SUBTOTAL function, which will ignore rows that are hidden (including those that are not visible due to a filter). So MAP in this revision is looking at your righthand table's Charge Code column. Depending on whether cells in the range P4:P8 have something in them (1's) or not (0's) dictates what the array looks like from the MAP function...and that array is then used to create a trimmed down list (an array) of the valid Charge Codes (in column P) that need to be considered when looking at the lefthand table...so the FILTER function needs to specify the P4:P8 range. Note that it is not critical that the MAP function refer to the P4:P8 range--this is somewhat arbitrary. Previously, I had MAP looking straight below and referencing cells in the righthand table in that same column, but it might be easier to follow the formula by always pointing to the Charge Code column.
Thank you again for the explanation, this is really helpful. Ok so this time it works in the mini sheet, however I am still having issue in the actual file. I feel like it is something small that needs to be configured or addressed in some way.

Firstly, since the mini sheet is now aligned to the actual reference sheet, I am able to copy your solution in 1:1 into the operational file, update the tab name for the reference data columns (A:N), update the Charge code (column P) reference and header reference (R3) and we are there. What I get in one case is #VALUE and in another Blank.

Case1 - #VALUE - when I get this error, the reference data columns (A - N) are used as COL:COL (A:A etc), the on sheet Charge code references are set as an absolute range ($P$4:$P$x).
Case2 - Blank - To investigate the error I changed the COL:COL references to an absolute range and I get the Blank return.

I also considered that (shot in the dark) maybe since the charge code range (col P) is a dynamic spilled array that I should reference it as P4# instead of P4:Px. This had no visible effect on the blank result.

Can you think of any sheet settings that I may need to consider? Since I am getting the correct result in the mini sheet there must be something I need to address in the operational file.
 
Upvote 0
Hi, small update to maybe help your thinking. I clicked on the error message box (yellow box) and selected "update to include cell references" and the blank return changed to a #N/A. Then I traced the error and it points to the first row of the charge code column (col P in the mini sheet). So this makes me think it has something to do with the dynamic spilled array in that column. Thoughts?

Another piece of the puzzle that may or may not be affecting the result. Charge code (col P) is not only a dynamic spilled array but is also a named range. That named range resides on another sheet and contains empty cells at it's bottom. The operational sheet in question is formatted to a range smaller than the named range it is pulling from. I have not had an issue with this for other array formulas just wanted to provide this info, in case it matters.
 
Last edited:
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,246
Members
452,623
Latest member
cliftonhandyman

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