Why does OR(AND()) fail @ 96 and again @ 100?

ToxinUK1

New Member
Joined
Sep 2, 2024
Messages
2
Office Version
  1. 365
Platform
  1. Windows
My sheet is supposed to translate network patch ports to network switch ports (TRUE = top row, FALSE = bottom row) but seems to fail after port 96 and then again at port 100.
The formula that I used is; =OR(AND(MID(B2,6,3)>"0",MID(B2,6,3)<"25"),AND(MID(B2,6,3)>"48",MID(B2,6,3)<"73"),AND(MID(B2,6,3)>"96",MID(B2,6,3)<"121"),AND(MID(B2,6,3)>"144",MID(B2,6,3)<"169"),AND(MID(B2,6,3)>"192",MID(B2,6,3)<"217")).
The data is arranged as 00/A/01 - 00/A/240.
It all works fine until it gets to 97 which should be TRUE but reports FALSE and then at 100 it reverts to TRUE and stays TRUE for the rest of the numbers.

MrExcel.JPG


Any help or alternatives would be appreciated.
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
You are doing text comparisons, not number ones. Text comparisons go character by character, so "2" would be > "197" because "2" is greater than "1" (it would never check the 9 or 7). Given that you have 365, I'd suggest using something like:

Excel Formula:
=LET(pnum,TEXTAFTER(B2,"/",-1)+0,OR(AND(pnum>0,pnum<25),AND(pnum>48,pnum<73),AND(pnum>96,pnum<121),AND(pnum>144,pnum<169),AND(pnum>192,pnum<217)))

You might also use a lookup table.
 
Upvote 0
One way:

Excel Formula:
=LET(a,REPLACE(B2,1,5,"")+0,SUM((a>{0,48,96,144,192})*(a<{25,73,121,169,217}))>0)
 
Upvote 0
Thanks for the explanation and both for the "better" way to calculate it. I'd completely missed the text versus number mismatch.
 
Upvote 0

Forum statistics

Threads
1,223,227
Messages
6,170,848
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