Make 365 Function Backward compatible with 2016 version

etaf

Well-known Member
Joined
Oct 24, 2012
Messages
8,295
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
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
I am not good with formulas but see if you can use this bit of info:

=UNIQUE(FILTER(A2:A9,A2:A9<>""))
Is equivalent to
=IFERROR(INDEX($A$2:$A$9, MATCH(0,IF(ISBLANK($A$2:$A$9),1,COUNTIF($G$2:G2, $A$2:$A$9)), 0)),"")

Then drag that formula down.
 
Upvote 0
I had to think back on how to do this in the old world. Try this:

Book1
ABCDEFGHIJ
1Woodother columnsother columnsthicknessMetresGroup by Wood & Thickness
2A0.10512RowWoodThicknessTotal
3C0.105121A0.10524
45B0.05215
5C0.038144C0.03828
6B0.052152C0.10512
7    
8C0.03814    
9A0.10512    
10    
Sheet1
Cell Formulas
RangeFormula
G3:G10G3=IFERROR(INDEX(ROW($A$2:$A$9),MATCH(0,IF($A$2:$A$9="",-1,COUNTIFS($A$2:$A$9,"<"&$A$2:$A$9)+COUNTIFS($A$2:$A$9,$A$2:$A$9,$D$2:$D$9,"<"&$D$2:$D$9)-SUM(COUNTIFS($A$2:$A$9,$H$2:$H2,$D$2:$D$9,$I$2:$I2))),0))-ROW($A$2)+1,"")
H3:H10H3=IF(G3="","",INDEX($A$2:$A$9,G3))
I3:I10I3=IF(G3="","",INDEX($D$2:$D$9,G3))
J3:J10J3=IF(G3="","",SUMIFS($E$2:$E$9,$A$2:$A$9,H3,$D$2:$D$9,I3))
Press CTRL+SHIFT+ENTER to enter array formulas.


I added a helper column in G with the matching row. Hide it if you don't want to see it. But you can definitely see why the new functions are so much nicer!
 
Upvote 0
Thanks for the replies
@johnnyL
=IFERROR(INDEX($A$2:$A$9, MATCH(0,IF(ISBLANK($A$2:$A$9),1,COUNTIF($G$2:G2, $A$2:$A$9)), 0)),"")
Thanks for that , useful to know , as i do occasionally need to use that older version - but as i'm I'm trying to find unique values of both wood and thickness - its not doing that , but thanks for taking the time in ,looking

@Eric W

Wow , that works OK, with the helper column , still going through to try and understand how its working - like you ages since i used 2016 version
But it looks like that will work for me - I'll try in the main sheet (so will not make solved yet)
and thanks for taking the time on this

Wayne
 
Upvote 0
not working correctly in the real data
i think because i have an IF() formula in all the cells and from what i can make out - its using a "" , and so I get blank for ALL in the real data, in the sample I get a load of blans and then the unique list.

trying to reproduce exactly the same error as the real data on a sample - to show
 
Upvote 0
i have now carried out a few tests and does seem like the formula generated "" is causing the issue
 
Upvote 0
Thanks for continuing to look

ok, its i have cut back the main file and showed some of the real data

if you look in cells
W20 to W31 - thats the 365 version

then in
Ab21 to Ae31
thats your formula converted

Now in cells I10 to I17
if you choose from the dropdown - NONE
that will make the equivalent cell blank in cells
I23 to I30

so if I10 to I17 has 1st/2nd 3rd in - then its OK
But as soon as NONE is chosen a blank occurs in I23 to I30 and it fails

in I23 I have
=IF(I10="none","",IF(I10="1st",$K$2,IF(I10="2nd",$K$3,$K$4)))
and so if I10 is NONE then blank

hope that helps - sorry its in a clunky spreadsheet - but thats more of the real data - cut down a bit

cheers

this is the file in dropbox

New Template 2022 - V103-Forum.xlsx
HIJKLMNOPQRSTUVWXYZAAABACADAEAFAGAH
1STEP 1: CHOOSE YOUR WOOD
2Primary WoodCerajeira
3Secondary WoodCerajeira
43rd WoodCastaña
5
6STEP 2: DEFINE ALL YOUR FNISHED ELEMENTS AND QUANTITIES OF EACH
7Final Dimensions
8
9WoodElementUnitsLength WidthThicknessm2WOOD
101stTaps11.20.07100120.084Cerajeira
112ndCabinet Top/Bottom13.040.0110.020.09424Cerajeira
12NonePatas1230.030.0251.98 
13NoneDraw extior face130.0310.020.153 
14NoneDraw fronts/back130.090.020.33 
153rdDraw sides130.150.020.51Castaña
161stSeperations130.0110.020.093Cerajeira
171st130.80.042.52Cerajeira
18125.76424ONLY WORKS with 365 VALUES
19
20RAW LUMBER DIMENSIONSGroup Material
21ElementlengththicknesswidthFinished WidthPer unit quantityAll Units quantityGroup by Wood & Thickness
22Woodm2m3Price/m3PriceMetresWoodThicknessTotalRowWoodThicknessTotal
23CerajeiraTaps3.60.1050.180.16110.6480.068041300€88.453.6Castaña 0.02702Cerajeira0.0277.2
24CerajeiraCabinet Top/Bottom3.60.0270.180.16110.6480.0174961580€27.643.6Cerajeira0.1053.63 0.0380
25 Patas3.60.0380.180.16131.9440.0738721300€96.03 Cerajeira0.0277.21Cerajeira0.1053.6
26 Draw extior face3.60.0270.180.16110.6480.0174961580€27.64 Cerajeira0.05218    
27 Draw fronts/back3.60.0270.180.16110.6480.0174961300€22.74      
28Castaña Draw sides3.60.0270.180.16110.6480.017496Not in Table       
29CerajeiraSeperations3.60.0270.180.16110.6480.0174961300€22.743.6     
30Cerajeira 3.60.0520.180.16553.240.16848 18     
3114€285.2628.828.810.8
32
33
34
35Boards length & width calculator Table
36BOARDS/RAW LGNTHBOARDS Req for WIDTHWIDTHS AvailablePER 1 UNITTOTAL PIECESTOTAL BOARDS
37Lenghts Available Per RAW UnitWidths Factor per Raw unitPossible Widths available to makePossible from RAW Unitfor Required QTYTo get the REQUIRED QTY
3820.504.0010.501
3910.205.0010.201
4010.254.0013.003
4110.254.0010.251
4211.001.0011.001
4311.001.0011.001
4410.205.0010.201
4515.000.2055.005
46
Test Template
Cell Formulas
RangeFormula
P10:P17P10=IF(I10="none","",IF(I10="1st",$K$2,IF(I10="2nd",$K$3,$K$4)))
O10:O17O10=SUM((M10+N10)*L10) *K10
O18,AE31,Y31,P31,T31:U31O18=SUM(O10:O17)
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)
T23:T30T23=IFERROR(SUM(R23*S23),"")
U23:U30U23=IF(OR(K10=0,I23="",S23="material Not Available",S23="Not in Table"),"",SUM(K23*P23))
W23:X26W23=SORT(UNIQUE(FILTER(FILTER(I23:M30,I23:I30<>""),{1,0,0,1,0})))
AB23AB23=IFERROR(INDEX(ROW($L$23:$L$30),MATCH(0,IF($L$23:$L$30="",-1,COUNTIFS($L$23:$L$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))),0))-ROW($I$23)+1,"")
AC23:AC30AC23=IF(AB23="","",INDEX($I$23:$I$30,AB23))
AD23:AD30AD23=IF(AB23="","",INDEX($L$23:$L$30,AB23))
AB24:AB30AB24=IFERROR(INDEX(ROW($L$23:$L$30),MATCH(0,IF($L$23:$L$30="",-1,COUNTIFS($L$23:$L$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))),0))-ROW($I$23)+1,"")
L23:L30L23=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))
AE23:AE30AE23=IF(AB23="","",SUMIFS($U$23:$U$30,$I$23:$I$30,AC23,$L$23:$L$30,AD23))
N38N38=FLOOR((K23-0.1)/(L10+0.04),1)
O38:O45O38=LOOKUP(M10,{0,0.026,0.036,0.051,0.071,0.16},{0.2,0.25,0.333334,0.5,1,1})*ROUNDUP(M10/N23,0)
P38:P45P38=N38/O38
Q38:Q45Q38=ROUNDUP(O38/N38,0)
R38:R45R38=O38*K10
S38:S45S38=ROUNDUP(R38/N38,0)
N39:N45N39=FLOOR(K24/L11,1)
Dynamic array formulas.
Cells with Conditional Formatting
CellConditionCell FormatStop If True
I10:I17Expression=OR(AND( I10="1st",$K$2="none"),AND( I10="2nd",$K$3="none"),AND( I10="3rd",$K$4="none"))textNO
K10:K17Expression=OR(AND((I10<>"none"),OR(K10="",K10=0)),AND(I10="none",OR(K10<>0,K10<>0)))textNO
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
Cells with Data Validation
CellAllowCriteria
I10:I17List='LIST DATA'!$B$5:$B$8
K2:N4List='LIST DATA'!$A$3:$A$41
K5:N5List=#REF!


lookup sheet
New Template 2022 - V103-Forum.xlsx
AB
1Wood name
2Nombre
3Abeto
4Arce blandaWood Selection
5Arce Duro1st
6Bubinga2nd
7Caoba3rd
8Castaña None
9Cedro Canadiense
10Cedro Tropical
11Cerajeira
12Cerezo USA
13Danta
14Ebano Tronco
15Elondo
16Fresno
17grapia
18Haya Vaparazada
19Ipe
20Iroko
21Jatoba
22Lenga
23Mongoy
24Nazereno
25Nogal USA
26Pino Gallego
27Pino Melix
28Pino Melix canto vivo
29Pino Suecia
30Pino Suecia V
31Pino Suecia VI
32Pino Vaisain
33Pino Vaisain MEJOR
34Poplar
35Roble EU
36Roble rojo
37Roble USA
38Roble Liston
39Sapelle
40Wengue
41None
42
LIST DATA
 
Upvote 0
Spend way too much time than I'd like to accept on this lol.

Formula for H3: =INDEX($A$2:$A$9,IF(LARGE(--($B$2:$B$9=1)*ROW($A$1:$A$8),ROW(A1))=0,"",LARGE(--($B$2:$B$9=1)*ROW($A$1:$A$8),ROW(A1))))
Formula for I3: =INDEX($E$2:$E$9,IF(LARGE(--($B$2:$B$9=1)*ROW($A$1:$A$8),ROW(A1))=0,"",LARGE(--($B$2:$B$9=1)*ROW($A$1:$A$8),ROW(A1))))
Helper column: =COUNTIFS($A$2:A2,A2,$E$2:E2,E2)
 

Attachments

  • ooo.PNG
    ooo.PNG
    37.7 KB · Views: 5
Upvote 0

Forum statistics

Threads
1,214,976
Messages
6,122,539
Members
449,088
Latest member
RandomExceller01

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