Make 365 Function Backward compatible with 2016 version

etaf

Well-known Member
Joined
Oct 24, 2012
Messages
8,696
Office Version
  1. 365
Platform
  1. MacOS
This is a nice to have at the moment
and i'm always interested in alternative ways to do things - BUT the main user of a larger spreadsheet i'm putting together is using 2016 , and may update later - BUT i would like if possible to male this work in 2016 version as well

For simplicity, I have created a very simple sample - just for the forum, which also works in the real data workbook, so hopefully no issues when i apply to the larger book

I have a formula in 365 version - using a UNQUE & FILTER function

This extracts a UNIQUE list , based on 2 NON-Contiguous columns , column A will contain blanks , which need to be ignored, as there will be a thickness and i dont want a group BLANK/THICKNESS

This is part of a much bigger spreadsheet and so I do NOT want to incorporate a pivot table as its part of a larger table , although i would use a pivot table if no simple solution, and change the layout - I have the pivot table in my example - XL2BB has shown the pivot table - BUT i have also put the sample on a share dropbox

I also do not want VBA - as again its part of a larger spreadsheet and avoiding VBA as much as possible, if i do add VBA later then i can incorporate it , but the vision is not to at the moment

Not end of world if not easy with Older 2016 versions Functions to replicate , its just the main person using the spreadsheet currently has 2016 version, although may in the future upgrade.... and i see a similar possible spreadsheet for my daughter framing material - and she has 2016 Mac version i think (which maybe 2011)

Sort is not that important - just i can do it in 365
=SORT(UNIQUE(FILTER(FILTER(A2:D9,A2:A9<>""),{1,0,0,1})))

I know the {1,0,0,1} allow for the NON Contiguous ranges - so only the 2 columns are output - WOOD/THICKNESS
And i found the Filter(Filter ( Excel Filter Function Trick Using Non-Adjacent Columns - Xelplus - Leila Gharani ) - part to also be able to add a criteria so blanks are ignored - which will appear anywhere in rows - and again the main table cannot be sorted

Then once i have extracted the UNIQUE Wood Type and Thickness - i then use a simple SUMIFS() to group into material - which is what i'm after


Group-Summary.xlsx
ABCDEFGHIJKLMN
1Woodother columnsother columnsthicknessMetresGroup by Wood & Thickness
2A0.10512WoodThicknessTotalWoodthicknessSum of Metres
3C0.10512A0.10524A0.10524
4B0.05215B0.05215
5C0.03814C0.10512C0.10512
6B0.05215C0.038280.03828
7 
8C0.03814 
9A0.10512 
Sheet1
Cell Formulas
RangeFormula
G3:H6G3=SORT(UNIQUE(FILTER(FILTER(A2:D9,A2:A9<>""),{1,0,0,1})))
I3:I9I3=IF(G3="","",SUMIFS($E$2:$E$9,$A$2:$A$9,G3,$D$2:$D$9,H3))
Dynamic array formulas.



Thanks for looking
 
really sorry , i know you are spending more time then needed on this
not working

New Template 2022 - V103-2.xlsx
AFAGAHAIAJ
13
14AH23: =INDEX($I$23:$I$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A$1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A$1))))
15AI23: =INDEX($M$23:$M$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A$1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A$1))))
16
17
18
19
20
21
22Helper
231Roble Liston0.18
241Roble Liston0.18
252Roble Liston0.18
261Roble Liston0.18
273Roble Liston0.18
282Roble Liston0.18
294Roble Liston0.18
301Roble Liston0.18
31
Test Template
Cell Formulas
RangeFormula
AG23:AG30AG23=COUNTIFS($I$23:I23,I23,$M$23:M23,M23)
AH23:AH30AH23=INDEX($I$23:$I$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A$1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A$1))))
AI23:AI30AI23=INDEX($M$23:$M$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A$1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A$1))))
copy paste this you're entering the formula wrong you're locking the row(a1)

AH23: =INDEX($I$23:$I$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW(A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW(A1))))
AI23: =INDEX($M$23:$M$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW(A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW(A1))))
 
Upvote 0

Excel Facts

Quick Sum
Select a range of cells. The total appears in bottom right of Excel screen. Right-click total to add Max, Min, Count, Average.
Thanks for that - working now - sorry about the typo - i used F4 to add the $ , rather than just edit for a single $

I can cope with the table with spaces in where we have a blank

New Template 2022 - V103-3 221130.xlsx
AGAHAIAJ
18Version 2016
19
20Group by Wood & Thickness
21
22HelperWoodThicknessTotal
231Cerezo USA0.0520
241Fresno0.0277.2
252Cerezo USA0.0273.6
261  0
271Fresno0.0383.6
283  0
292  0
301  0
3114.4
Test Template
Cell Formulas
RangeFormula
AG23:AG30AG23=COUNTIFS($I$23:I23,I23,$L$23:L23,L23)
AH23:AH30AH23=IFERROR(INDEX($I$23:$I$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1)))),"")
AI23:AI30AI23=IFERROR(INDEX($L$23:$L$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1)))),"")
AJ23:AJ30AJ23=SUMIFS($U$23:$U$30,$I$23:$I$30,AH23,$L$23:$L$30,AI23)
AJ31AJ31=SUM(AJ23:AJ30)
 
Upvote 0
Thanks for that - working now - sorry about the typo - i used F4 to add the $ , rather than just edit for a single $

I can cope with the table with spaces in where we have a blank

New Template 2022 - V103-3 221130.xlsx
AGAHAIAJ
18Version 2016
19
20Group by Wood & Thickness
21
22HelperWoodThicknessTotal
231Cerezo USA0.0520
241Fresno0.0277.2
252Cerezo USA0.0273.6
261  0
271Fresno0.0383.6
283  0
292  0
301  0
3114.4
Test Template
Cell Formulas
RangeFormula
AG23:AG30AG23=COUNTIFS($I$23:I23,I23,$L$23:L23,L23)
AH23:AH30AH23=IFERROR(INDEX($I$23:$I$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1)))),"")
AI23:AI30AI23=IFERROR(INDEX($L$23:$L$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1)))),"")
AJ23:AJ30AJ23=SUMIFS($U$23:$U$30,$I$23:$I$30,AH23,$L$23:$L$30,AI23)
AJ31AJ31=SUM(AJ23:AJ30)
Are you sure about that? because Helper column is pulling 5 values of 1 and column AH only has a total of 4 values.

=COUNTIFS($I$23:I23,I23,$L$23:L23,L23)

isn't thickness in column starting from M23 instead of L23
 
Upvote 0
isn't thickness in column starting from M23 instead of L23
yes in the example , as it had the helper column in B - when i moved things around - i didnt delete that column
so now its in L

New Template 2022 - V104-1.xlsx
IJKLMNOPQRSTUVWXYZAEAFAGAHAIAJAK
19
20RAW LUMBER DIMENSIONSGroup MaterialGroup by Wood & Thickness
21ElementlengththicknesswidthFinished WidthPer unit quantityAll Units quantity
22Woodm2m3Price/m3PriceMetresWoodThicknessTotalHelperWoodThicknessTotal
23FresnoTaps3.60.0380.180.16110.6480.0246241310€32.263.6Caoba0.02701Cerezo USA0.0520
24Cerezo USACabinet Top/Bottom3.60.0270.180.16110.6480.0174962300€40.243.6Cerezo USA0.0273.61Fresno0.0277.2
25FresnoPatas3.60.0380.180.16131.9440.0738721310€96.7710.8Cerezo USA0.05202Caoba0.0270
26CaobaDraw extior face3.60.0270.180.16110.6480.017496Material Not Available  Fresno0.03814.41Cerezo USA0.0273.6
27FresnoDraw fronts/back3.60.0270.180.16110.6480.0174961350€23.623.6Fresno0.0277.21Fresno0.03814.4
28CaobaDraw sides3.60.0270.180.16110.6480.017496Material Not Available   2  0
29FresnoSeperations3.60.0270.180.16110.6480.0174961350€23.623.6 2  0
30Cerezo USA 3.60.0520.180.16553.240.16848Material Not Available   1  0
3114€216.5125.225.225.2
32
Test Template
Cell Formulas
RangeFormula
I23:I30I23=IF(I10="none","",IF(I10="1st",$K$2,IF(I10="2nd",$K$3,$K$4)))
J23:J30J23=IF(J10="","",J10)
N23:N30N23=SUM(M23-0.02)
O23:O30O23=Q38
Q23:Q30Q23=SUM(K23*M23*P23)
R23:R30R23=SUM(K23*L23*M23*P23)
S23:S30S23=IF(OR(I10="none",K10=0),"",IFERROR(IF(INDEX('Wood Prices'!$C$2:$K$40,MATCH(IF(I10="1st",$K$2,IF(I10="2nd",$K$3,$K$4)),'Wood Prices'!$A$2:$A$40,0),MATCH($L23*1000,'Wood Prices'!$C$1:$K$1,0))=0,"Material Not Available", INDEX('Wood Prices'!$C$2:$K$40,MATCH(IF(I10="1st",$K$2,IF(I10="2nd",$K$3,$K$4)),'Wood Prices'!$A$2:$A$40,0),MATCH($L23*1000,'Wood Prices'!$C$1:$K$1,0))),"Not in Table"))
T23:T30T23=IFERROR(SUM(R23*S23),"")
U23:U30U23=IF(OR(K10=0,I23="",S23="material Not Available",S23="Not in Table"),"",SUM(K23*P23))
T31:U31,AJ31,Y31,P31T31=SUM(T23:T30)
W23:X27W23=SORT(UNIQUE(FILTER(FILTER(I23:L30,I23:I30<>""),{1,0,0,1})))
AG23:AG30AG23=COUNTIFS($I$23:I23,I23,$L$23:L23,L23)
AH23:AH30AH23=IFERROR(INDEX($I$23:$I$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1)))),"")
AI23:AI30AI23=IFERROR(INDEX($L$23:$L$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1)))),"")
L23:L30L23=IF(I23="","",IF(N10>0.07,0.105,IF(N10>0.044,0.076,IF(N10>0.032,0.052,IF(N10>0.022,0.038,IF(N10>0.011,0.027,"Invalid Thickness"))))))
P23:P30P23=S38
Y23:Y30Y23=IF(W23="","",SUMIFS($U$23:$U$30,$I$23:$I$30,W23,$L$23:$L$30,X23))
AJ23:AJ30AJ23=SUMIFS($U$23:$U$30,$I$23:$I$30,AH23,$L$23:$L$30,AI23)
Dynamic array formulas.
Cells with Conditional Formatting
CellConditionCell FormatStop If True
J23:U30Expression=$K10=0textNO
S23:S30Expression=OR(S23="Material Not Available",S23="Not in table")textNO
I23:I30Expression=$I10="3rd"textYES
I23:I30Expression=$I10="2nd"textYES
I23:I30Expression=$I10="1st"textYES
I10:I17,V23:V30Expression=AND(I10="3rd",$K$4<>"None")textNO
I10:I17,V23:V30Cell Valuecontains "2nd"textNO
I10:I17,V23:V30Cell Valuecontains "1st"textNO


New Template 2022 - V104-1.xlsx
IJKLMNOPQRSTUVWXYZAEAFAGAHAIAJAK
19
20RAW LUMBER DIMENSIONSGroup MaterialGroup by Wood & Thickness
21ElementlengththicknesswidthFinished WidthPer unit quantityAll Units quantity
22Woodm2m3Price/m3PriceMetresWoodThicknessTotalHelperWoodThicknessTotal
23FresnoTaps3.60.0380.180.16110.6480.0246241310€32.263.6Caoba0.02701Cerezo USA0.0520
24 Cabinet Top/Bottom3.6 0.180.16110.648#VALUE!   Cerezo USA0.05201Fresno0.0277.2
25FresnoPatas3.60.0380.180.16131.9440.0738721310€96.7710.8Fresno0.03814.42Caoba0.0270
26CaobaDraw extior face3.60.0270.180.16110.6480.017496Material Not Available  Fresno0.0277.21  0
27FresnoDraw fronts/back3.60.0270.180.16110.6480.0174961350€23.623.6 1Fresno0.03814.4
28 Draw sides3.6 0.180.16110.648#VALUE!    2  0
29FresnoSeperations3.60.0270.180.16110.6480.0174961350€23.623.6 2  0
30Cerezo USA 3.60.0520.180.16553.240.16848Material Not Available   1  0
3114€176.2721.621.621.6
32
Test Template
Cell Formulas
RangeFormula
I23:I30I23=IF(I10="none","",IF(I10="1st",$K$2,IF(I10="2nd",$K$3,$K$4)))
J23:J30J23=IF(J10="","",J10)
N23:N30N23=SUM(M23-0.02)
O23:O30O23=Q38
Q23:Q30Q23=SUM(K23*M23*P23)
R23:R30R23=SUM(K23*L23*M23*P23)
S23:S30S23=IF(OR(I10="none",K10=0),"",IFERROR(IF(INDEX('Wood Prices'!$C$2:$K$40,MATCH(IF(I10="1st",$K$2,IF(I10="2nd",$K$3,$K$4)),'Wood Prices'!$A$2:$A$40,0),MATCH($L23*1000,'Wood Prices'!$C$1:$K$1,0))=0,"Material Not Available", INDEX('Wood Prices'!$C$2:$K$40,MATCH(IF(I10="1st",$K$2,IF(I10="2nd",$K$3,$K$4)),'Wood Prices'!$A$2:$A$40,0),MATCH($L23*1000,'Wood Prices'!$C$1:$K$1,0))),"Not in Table"))
T23:T30T23=IFERROR(SUM(R23*S23),"")
U23:U30U23=IF(OR(K10=0,I23="",S23="material Not Available",S23="Not in Table"),"",SUM(K23*P23))
T31:U31,AJ31,Y31,P31T31=SUM(T23:T30)
W23:X26W23=SORT(UNIQUE(FILTER(FILTER(I23:L30,I23:I30<>""),{1,0,0,1})))
AG23:AG30AG23=COUNTIFS($I$23:I23,I23,$L$23:L23,L23)
AH23:AH30AH23=IFERROR(INDEX($I$23:$I$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1)))),"")
AI23:AI30AI23=IFERROR(INDEX($L$23:$L$30,IF(LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1))=0,"",LARGE(--($AG$23:$AG$30=1)*ROW($A$1:$A$8),ROW($A1)))),"")
L23:L30L23=IF(I23="","",IF(N10>0.07,0.105,IF(N10>0.044,0.076,IF(N10>0.032,0.052,IF(N10>0.022,0.038,IF(N10>0.011,0.027,"Invalid Thickness"))))))
P23:P30P23=S38
Y23:Y30Y23=IF(W23="","",SUMIFS($U$23:$U$30,$I$23:$I$30,W23,$L$23:$L$30,X23))
AJ23:AJ30AJ23=SUMIFS($U$23:$U$30,$I$23:$I$30,AH23,$L$23:$L$30,AI23)
Dynamic array formulas.
Cells with Conditional Formatting
CellConditionCell FormatStop If True
J23:U30Expression=$K10=0textNO
S23:S30Expression=OR(S23="Material Not Available",S23="Not in table")textNO
I23:I30Expression=$I10="3rd"textYES
I23:I30Expression=$I10="2nd"textYES
I23:I30Expression=$I10="1st"textYES
I10:I17,V23:V30Expression=AND(I10="3rd",$K$4<>"None")textNO
I10:I17,V23:V30Cell Valuecontains "2nd"textNO
I10:I17,V23:V30Cell Valuecontains "1st"textNO
 
Upvote 0
I based this adaptation on the mini-sheet from post 9. I didn't realize at the time that there are 2 additional pages of posts:

Book1
WXYZAAABACADAE
20Group Material
21Group by Wood & Thickness
22WoodThicknessTotalRowWoodThicknessTotal
23Castaña 0.02706Castaña 0.0270
24Cerajeira0.0277.22Cerajeira0.0277.2
25Cerajeira0.052188Cerajeira0.05218
26Cerajeira0.1053.61Cerajeira0.1053.6
27     
Sheet1
Cell Formulas
RangeFormula
W23:X26W23=SORT(UNIQUE(FILTER(FILTER(I23:M30,I23:I30<>""),{1,0,0,1,0})),{1,2})
AB23AB23=IFERROR(INDEX(ROW($L$23:$L$30),MATCH(0,IF($I$23:$I$30="",-1,COUNTIFS($I$23:$I$30,"<"&$I$23:$I$30)+COUNTIFS($I$23:$I$30,$I$23:$I$30,$L$23:$L$30,"<"&$L$23:$L$30)-SUM(COUNTIFS($I$23:$I$30,$AC22:$AC$22,$L$23:$L$30,$AD22:$AD$22))-COUNTIF($I$23:$I$30,"")),0))-ROW($I$23)+1,"")
AC23:AC27AC23=IF(AB23="","",INDEX($I$23:$I$30,AB23))
AD23:AD27AD23=IF(AB23="","",INDEX($L$23:$L$30,AB23))
AE23:AE27AE23=IF(AB23="","",SUMIFS($U$23:$U$30,$I$23:$I$30,AC23,$L$23:$L$30,AD23))
AB24:AB27AB24=IFERROR(INDEX(ROW($L$23:$L$30),MATCH(0,IF($I$23:$I$30="",-1,COUNTIFS($I$23:$I$30,"<"&$I$23:$I$30)+COUNTIFS($I$23:$I$30,$I$23:$I$30,$L$23:$L$30,"<"&$L$23:$L$30)-SUM(COUNTIFS($I$23:$I$30,$AC$22:$AC23,$L$23:$L$30,$AD$22:$AD23))-COUNTIF($I$23:$I$30,"")),0))-ROW($I$23)+1,"")
Y23:Y27Y23=IF(W23="","",SUMIFS($U$23:$U$30,$I$23:$I$30,W23,$L$23:$L$30,X23))
Press CTRL+SHIFT+ENTER to enter array formulas.
Dynamic array formulas.


This should handle the empty rows better. I only had to add one extra COUNTIF term. Also I tweaked the 365 formula a bit so that the thicknesses are also sorted.

I'm going to take a look at shinigamilight's formulas. They are shorter, so that's a plus. My formulas are designed to sort the list too, so that's also a consideration.

 
Upvote 0
Solution
@Eric W
Thanks for the follow-up
Copied that into the main "real" data and it works perfectly

Thanks to both for all the time you are taken in answering
 
Upvote 0

Forum statistics

Threads
1,223,231
Messages
6,170,884
Members
452,364
Latest member
springate

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