Nestling: The specified formula cannot be entered because it uses more than 64 levels of nestling

Beunite

New Member
Joined
Apr 22, 2016
Messages
4
Hi there,

I'm new to the community. Please help me to follow the right procedures.

I have a problem with nestling and I need your help.

Here's the formula, it's a simple ifand formula. The formula works like a beauty until the last city (Yangon). Then the error message pops up.

The specified formula cannot be entered because it uses more than 64 levels of nestling

It consists of the cities, Bangkok, Phuket, KohSamui, etc. and the duration half-day, full-day, two-day, etc. so it pretty much repeats itself from the beginning up until the with all combinations of cities and duration. I will have more cities to add in the future, up to 50.

I hope it's not too long and doesn't cause confusion:

Thank you for helping me to crack this nut.

Kind regards

This is the formula that works up until Yangon:

=IF(AND($C4="Bangkok",$A4="shorter than half-day"),Accommodation!$B$2,IF(AND($C4="Bangkok",$A4="half-day"),Accommodation!$B$3,IF(AND($C4="Bangkok",$A4="full-day"),Accommodation!$B$4,IF(AND($C4="Bangkok",$A4="two-day"),Accommodation!$B$5,IF(AND($C4="Bangkok",$A4="longer than two days"),Accommodation!$B$6,IF(AND($C4="Phuket",$A4="shorter than half-day"),Accommodation!$C$2,IF(AND($C4="Phuket",$A4="half-day"),Accommodation!$C$3,IF(AND($C4="Phuket",$A4="full-day"),Accommodation!$C4,IF(AND($C4="Phuket",$A4="two-day"),Accommodation!$C$5,IF(AND($C4="Phuket",$A4="longer than two days"),Accommodation!$C$6,IF(AND($C4="Koh Samui",$A4="shorter than half-day"),Accommodation!$D$2,IF(AND($C4="Koh Samui",$A4="half-day"),Accommodation!$D$3,IF(AND($C4="Koh Samui",$A4="full-day"),Accommodation!$D$4,IF(AND($C4="Koh Samui",$A4="two-day"),Accommodation!$D$5,IF(AND($C4="Koh Samui",$A4="longer than two days"),Accommodation!$D$6,IF(AND($C4="Hua Hin",$A4="shorter than half-day"),Accommodation!$E$2,IF(AND($C4="Hua Hin",$A4="half-day"),Accommodation!$E$3,IF(AND($C4="Hua Hin",$A4="full-day"),Accommodation!$E$4,IF(AND($C4="Hua Hin",$A4="two-day"),Accommodation!$E$5,IF(AND($C4="Hua Hin",$A4="longer than two days"),Accommodation!$E$6,IF(AND($C4="Pattaya",$A4="shorter than half-day"),Accommodation!$F$2,IF(AND($C4="Pattaya",$A4="half-day"),Accommodation!$F$3,IF(AND($C4="Pattaya",$A4="full-day"),Accommodation!$F$4,IF(AND($C4="Pattaya",$A4="two-day"),Accommodation!$F$5,IF(AND($C4="Pattaya",$A4="longer than two days"),Accommodation!$F$6,IF(AND($C4="Chiang Mai",$A4="shorter than half-day"),Accommodation!$G$2,IF(AND($C4="Chiang Mai",$A4="half-day"),Accommodation!$G$3,IF(AND($C4="Chiang Mai",$A4="full-day"),Accommodation!$G$4,IF(AND($C4="Chiang Mai",$A4="two-day"),Accommodation!$G$5,IF(AND($C4="Chiang Mai",$A4="longer than two days"),Accommodation!$G$6, IF(AND($C4="Singapore",$A4="shorter than half-day"),Accommodation!$H$2,IF(AND($C4="Singapore",$A4="half-day"),Accommodation!$H$3,IF(AND($C4="Singapore",$A4="full-day"),Accommodation!$H$4,IF(AND($C4="Singapore",$A4="two-day"),Accommodation!$H$5,IF(AND($C4="Singapore",$A4="longer than two days"),Accommodation!$H$6, IF(AND($C4="Hong Kong",$A4="shorter than half-day"),Accommodation!$I$2,IF(AND($C4="Hong Kong",$A4="half-day"),Accommodation!$I$3,IF(AND($C4="Hong Kong",$A4="full-day"),Accommodation!$I$4,IF(AND($C4="Hong Kong",$A4="two-day"),Accommodation!$I$5,IF(AND($C4="Hong Kong",$A4="longer than two days"),Accommodation!$I$6,IF(AND($C4="Kuala Lumpur",$A4="shorter than half-day"),Accommodation!$J$2,IF(AND($C4="Kuala Lumpur",$A4="half-day"),Accommodation!$J$3,IF(AND($C4="Kuala Lumpur",$A4="full-day"),Accommodation!$J$4,IF(AND($C4="Kuala Lumpur",$A4="two-day"),Accommodation!$J$5,IF(AND($C4="Kuala Lumpur",$A4="longer than two days"),Accommodation!$J$6,IF(AND($C4="Jakarta",$A4="shorter than half-day"),Accommodation!$K$2,IF(AND($C4="Jakarta",$A4="half-day"),Accommodation!$K$3,IF(AND($C4="Jakarta",$A4="full-day"),Accommodation!$K$4,IF(AND($C4="Jakarta",$A4="two-day"),Accommodation!$K$5,IF(AND($C4="Jakarta",$A4="longer than two days"),Accommodation!$K$6,IF(AND($C4="Siem Reap",$A4="shorter than half-day"),Accommodation!$L$2,IF(AND($C4="Siem Reap",$A4="half-day"),Accommodation!$L$3,IF(AND($C4="Siem Reap",$A4="full-day"),Accommodation!$L$4,IF(AND($C4="Siem Reap",$A4="two-day"),Accommodation!$L$5,IF(AND($C4="Siem Reap",$A4="longer than two days"),Accommodation!$L$6,IF(AND($C4="Yangon",$A4="shorter than half-day"),Accommodation!$M$2,IF(AND($C4="Yangon",$A4="half-day"),Accommodation!$M$3, IF(AND($C4="Yangon",$A4="full-day"),Accommodation!$M$4,IF(AND($C4="Yangon",$A4="two-day"),Accommodation!$M$5,IF(AND($C4="Yangon",$A4="longer than two days"),Accommodation!$M$6 ))))))))))))))))))))))))))))))))))))))))))))))))))))))) )))))

This is the last part of the formula that doesn't work when added to the previous one:

,IF(AND($C4="Colombo",$A4="shorter than half-day"),'ACCOMMODATION'!$N$2,IF(AND($C4="Colombo",$A4="half-day"),'ACCOMMODATION'!$N$3,IF(AND($C4="Colombo",$A4="full-day"),'ACCOMMODATION'!$N$4,IF(AND($C4="Colombo",$A4="two-day"),'ACCOMMODATION'!$N$5,IF(AND($C4="Colombo",$A4="longer than two days"),'ACCOMMODATION'!$N$6 )))))


This is the entire formula that unfortunately doesn't work:

=IF(AND($C4="Bangkok",$A4="shorter than half-day"),Accommodation!$B$2,IF(AND($C4="Bangkok",$A4="half-day"),Accommodation!$B$3,IF(AND($C4="Bangkok",$A4="full-day"),Accommodation!$B$4,IF(AND($C4="Bangkok",$A4="two-day"),Accommodation!$B$5,IF(AND($C4="Bangkok",$A4="longer than two days"),Accommodation!$B$6,IF(AND($C4="Phuket",$A4="shorter than half-day"),Accommodation!$C$2,IF(AND($C4="Phuket",$A4="half-day"),Accommodation!$C$3,IF(AND($C4="Phuket",$A4="full-day"),Accommodation!$C4,IF(AND($C4="Phuket",$A4="two-day"),Accommodation!$C$5,IF(AND($C4="Phuket",$A4="longer than two days"),Accommodation!$C$6,IF(AND($C4="Koh Samui",$A4="shorter than half-day"),Accommodation!$D$2,IF(AND($C4="Koh Samui",$A4="half-day"),Accommodation!$D$3,IF(AND($C4="Koh Samui",$A4="full-day"),Accommodation!$D$4,IF(AND($C4="Koh Samui",$A4="two-day"),Accommodation!$D$5,IF(AND($C4="Koh Samui",$A4="longer than two days"),Accommodation!$D$6,IF(AND($C4="Hua Hin",$A4="shorter than half-day"),Accommodation!$E$2,IF(AND($C4="Hua Hin",$A4="half-day"),Accommodation!$E$3,IF(AND($C4="Hua Hin",$A4="full-day"),Accommodation!$E$4,IF(AND($C4="Hua Hin",$A4="two-day"),Accommodation!$E$5,IF(AND($C4="Hua Hin",$A4="longer than two days"),Accommodation!$E$6,IF(AND($C4="Pattaya",$A4="shorter than half-day"),Accommodation!$F$2,IF(AND($C4="Pattaya",$A4="half-day"),Accommodation!$F$3,IF(AND($C4="Pattaya",$A4="full-day"),Accommodation!$F$4,IF(AND($C4="Pattaya",$A4="two-day"),Accommodation!$F$5,IF(AND($C4="Pattaya",$A4="longer than two days"),Accommodation!$F$6,IF(AND($C4="Chiang Mai",$A4="shorter than half-day"),Accommodation!$G$2,IF(AND($C4="Chiang Mai",$A4="half-day"),Accommodation!$G$3,IF(AND($C4="Chiang Mai",$A4="full-day"),Accommodation!$G$4,IF(AND($C4="Chiang Mai",$A4="two-day"),Accommodation!$G$5,IF(AND($C4="Chiang Mai",$A4="longer than two days"),Accommodation!$G$6, IF(AND($C4="Singapore",$A4="shorter than half-day"),Accommodation!$H$2,IF(AND($C4="Singapore",$A4="half-day"),Accommodation!$H$3,IF(AND($C4="Singapore",$A4="full-day"),Accommodation!$H$4,IF(AND($C4="Singapore",$A4="two-day"),Accommodation!$H$5,IF(AND($C4="Singapore",$A4="longer than two days"),Accommodation!$H$6, IF(AND($C4="Hong Kong",$A4="shorter than half-day"),Accommodation!$I$2,IF(AND($C4="Hong Kong",$A4="half-day"),Accommodation!$I$3,IF(AND($C4="Hong Kong",$A4="full-day"),Accommodation!$I$4,IF(AND($C4="Hong Kong",$A4="two-day"),Accommodation!$I$5,IF(AND($C4="Hong Kong",$A4="longer than two days"),Accommodation!$I$6,IF(AND($C4="Kuala Lumpur",$A4="shorter than half-day"),Accommodation!$J$2,IF(AND($C4="Kuala Lumpur",$A4="half-day"),Accommodation!$J$3,IF(AND($C4="Kuala Lumpur",$A4="full-day"),Accommodation!$J$4,IF(AND($C4="Kuala Lumpur",$A4="two-day"),Accommodation!$J$5,IF(AND($C4="Kuala Lumpur",$A4="longer than two days"),Accommodation!$J$6,IF(AND($C4="Jakarta",$A4="shorter than half-day"),Accommodation!$K$2,IF(AND($C4="Jakarta",$A4="half-day"),Accommodation!$K$3,IF(AND($C4="Jakarta",$A4="full-day"),Accommodation!$K$4,IF(AND($C4="Jakarta",$A4="two-day"),Accommodation!$K$5,IF(AND($C4="Jakarta",$A4="longer than two days"),Accommodation!$K$6,IF(AND($C4="Siem Reap",$A4="shorter than half-day"),Accommodation!$L$2,IF(AND($C4="Siem Reap",$A4="half-day"),Accommodation!$L$3,IF(AND($C4="Siem Reap",$A4="full-day"),Accommodation!$L$4,IF(AND($C4="Siem Reap",$A4="two-day"),Accommodation!$L$5,IF(AND($C4="Siem Reap",$A4="longer than two days"),Accommodation!$L$6,IF(AND($C4="Yangon",$A4="shorter than half-day"),Accommodation!$M$2,IF(AND($C4="Yangon",$A4="half-day"),Accommodation!$M$3, IF(AND($C4="Yangon",$A4="full-day"),Accommodation!$M$4,IF(AND($C4="Yangon",$A4="two-day"),Accommodation!$M$5,IF(AND($C4="Yangon",$A4="longer than two days"),Accommodation!$M$6 ,IF(AND($C4="Colombo",$A4="shorter than half-day"),'ACCOMMODATION'!$N$2,IF(AND($C4="Colombo",$A4="half-day"),'ACCOMMODATION'!$N$3,IF(AND($C4="Colombo",$A4="full-day"),'ACCOMMODATION'!$N$4,IF(AND($C4="Colombo",$A4="two-day"),'ACCOMMODATION'!$N$5,IF(AND($C4="Colombo",$A4="longer than two days"),'ACCOMMODATION'!$N$6 ))))))))))))))))))))))))))))))))))))))))))))))))))))))) ))))) )))))
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
You really shouldn't be trying to use IF tests for that. Apart from anything else, they're a maintenance nightmare. And, as you have discovered, you can only nest them so far...

What you should do is create a lookup table, which would then allow you to use one of Excel's LOOKUP functions or an INDEX/MATCH function combination.
 
Upvote 0
Looks like you already have a table in "Accommodation" sheet.

Make your table like this in "Accommodation" Sheet:

Note: The numbers generated are random numbers as I don't know the result of matching criteria.


Excel 2016
ABCDEF
1shorter then half-dayhalf-dayfull-daytwo-daylonger then two day
2Bangkok292128157485214
3phuket244263165386258
4Koh Samui320445191431407
5Hua Hin228491321141424
6Pattaya177222204322203
7Chiang Mai193186125169139
8Singapore304398261269221
9Hong Kong493135427241330
10Kuala Lumpur274305427215419
11Jakarta441139128419499
12Siem Reap242321400374273
13Yangon243399319138493
14Colombo363487401448141
Accommodation


And your Result sheet like this:


Excel 2016
ABCDEF
1shorter then half-dayhalf-dayfull-daytwo-daylonger then two day
2Bangkok292128157485214
3phuket244263165386258
4Koh Samui320445191431407
5Hua Hin228491321141424
6Pattaya177222204322203
7Chiang Mai193186125169139
8Singapore304398261269221
9Hong Kong493135427241330
10Kuala Lumpur274305427215419
11Jakarta441139128419499
12Siem Reap242321400374273
13Yangon243399319138493
14Colombo363487401448141
Accommodation


<tbody></tbody>
 
Last edited:
Upvote 0
Hi guys, thank you so much for your reply. I have studied the lookup, vlookup and index/match functions but wasn't able to make it work.

Here is a more detailed description of the problem:

On one work sheet (Calculation) I have Destination on column E, and category in Column F. It looks like this:

Calculation
E F
1 Bangkok Half-day
2 Phuket Full-day
3 Koh Samui Two-day

And in another spreadsheet (Accommodation) I have....

Accommodation
A B C D E
Duration Bangkok Phuket Koh Samui
1 Half-day 3 43 43
2 Full-day 5 61 72
3 Two-day 8 75 80

The end result should be in spreadsheet "Calculation" in column DW

Calculation
DW
1 3
2 61
3 80

Can somebody please help me with a substitute formula for ifand? An easy low maintenance solution?
 
Upvote 0
For better lay out:

Calculation
E F
1 Bangkok Half-day
2 Phuket Full-day
3 Koh Samui Two-day
Accommodation
A B C D E
Duration Bangkok Phuket Koh Samui
1Half-day 34343
2 Full-day 56172
3Two-day87580
Calculation (formula retreives answer in column DW)
DW
13
261
380
Calculation (end result)
E FDW
1 Bangkok Half-day3
2 Phuket Full-day61
3 Koh Samui Two-day80

<colgroup><col span="5"></colgroup><tbody>
</tbody>
 
Upvote 0
Accommodation Table:


Excel 2016
ABCDEFGHIJKLMNO
1S.NoCountry DurationBangkokphuketKoh SamuiHua HinPattayaChiang MaiSingaporeHong KongKuala LumpurJakartaSiem ReapYangonColombo
21shorter then half-day1254402184071034444987429374380482492
32half-day313383481135148642175182955533416
43full-day2368548064163572402092988447174411
54two-day2831383173063451914248144431109292379
65longer then two day267421350101272204189213378362451139187
Accommodation


Result Sheet:


Excel 2016
EFDW
1CountryDayResult
2Bangkokshorter then half-day125
3
Calculation
Cell Formulas
RangeFormula
DW2=VLOOKUP(F2,Accommodation!$B$2:$O$6,MATCH(E2,Accommodation!$B$1:$O$1,0),0)
 
Upvote 0
Hi Nishant 94,

This was fantastic. Such a wonderful formula. It works like a beauty. You have saved me tons of time.

Big thank you and my appreciation for your help:)

Kind regards
Beunite

p.s great forum and I will come back here next time.


 
Upvote 0

Forum statistics

Threads
1,214,431
Messages
6,119,458
Members
448,899
Latest member
maplemeadows

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