Table Formula Throws VALUE Error at Bottom of Column

NorthbyNorthwest

Board Regular
Joined
Oct 27, 2013
Messages
173
Office Version
  1. 365
Hi, everyone. I have a formula copied down a column "DC", rows 6 - 89. Formula works until row 84 when a VALUE error occurs. The formula is simple. It's in column "DC" and references the cell to the immediate left, in column "DB."" Why would a formula that worked for 70+ rows suddenly throw an error? Attached is a pic of the table.

The formula in column "DC" is =IF($DB6="","",SUBSTITUTE(SUBSTITUTE(LEFT($DB6,SEARCH("]",$DB6)),"[",""),"]",""))

Copied down the errors start in row 84, =IF($DB84="","",SUBSTITUTE(SUBSTITUTE(LEFT($DB84,SEARCH("]",$DB84)),"[",""),"]",""))

There is also a formula copied down column "DB". It is =IFERROR(IF([@Employee]="","",CONCAT(tblDetails[@[Err1]:[Err23]],tblDetails[@[Err30]:[Err46]])),""). If I remove this formula from a cell in column "DB" and replace with a real value, then the formula in "DC" works. So, is there a problem with the formula in column "DB"? Is yes, what is it?

Any assistance would be appreciated. Thanks in advance.
 

Attachments

  • MExcel snippet 1.jpg
    MExcel snippet 1.jpg
    35.7 KB · Views: 10

Excel Facts

Who is Mr Spreadsheet?
Author John Walkenbach was Mr Spreadsheet until his retirement in June 2019.
Have a close look at what you've got in cell DB84. It's not blank, otherwise your formula would have returned "".

Is it perhaps one or more space characters? To test, try the formula: =LEN(DB84) in another cell.

If that is the problem, you could test: =IF(TRIM($DB84)="","",SUBSTITUTE ...
 
Last edited:
Upvote 0
By the way, if you are only going to use Excel365, you could use the TEXTBEFORE and TEXTAFTER functions instead.

But it's not clear what column DB might contain? If it's just one error value wrapped in [ ], you could just strip the first and last characters.

Are multiple errors concatenated, e.g. [1111][2222] a possibility?
 
Upvote 0
.. or tidy up the space(s) in column DB with
=IFERROR(IF([@Employee]="","",TRIM(CONCAT(tblDetails[@[Err1]:[Err23]],tblDetails[@[Err30]:[Err46]]))),"")
 
Upvote 0
Have a close look at what you've got in cell DB84. It's not blank, otherwise your formula would have returned "".

Is it perhaps one or more space characters? To test, try the formula: =LEN(DB84) in another cell.

If that is the problem, you could test: =IF(TRIM($DB84)="","",SUBSTITUTE ...
Thanks Stephen. You were right. LEN(DB84) = 1. So I went back to the cells referenced in the CONCAT formula ((tblDetails[@[Err1]:[Err23]],tblDetails[@[Err30]:[Err46]])) and cleared the cells. The LEN formula then returned a zero.
 
Upvote 0
By the way, if you are only going to use Excel365, you could use the TEXTBEFORE and TEXTAFTER functions instead.

But it's not clear what column DB might contain? If it's just one error value wrapped in [ ], you could just strip the first and last characters.

Are multiple errors concatenated, e.g. [1111][2222] a possibility?
Yes, Stephen. The formula is concatenating a series of numbers encased by brackets. Then I have to break out each number into an individual cell minus the brackets. So, if DB84 formula returned
[309][320][1404][1601][2000][2002] I have formulas to break out numbers. In this example formulas are:

DC84 =IF(DB84="","",SUBSTITUTE(SUBSTITUTE(LEFT(DB84,SEARCH("]",DB84)),"[",""),"]",""))


DD84 =IF(DB84="","",SUBSTITUTE(SUBSTITUTE(TRIM(MID(SUBSTITUTE(TRIM(DB84),"]",REPT("]",LEN(DB84))), 1*LEN(DB84)+1, LEN(DB84))),"]",""),"[",""))


DE84 =IF(DB84="","",SUBSTITUTE(SUBSTITUTE(TRIM(MID(SUBSTITUTE(TRIM(DB84),"]",REPT("]",LEN(DB84))), 2*LEN(DB84)+1, LEN(DB84))),"]",""),"[",""))


DF84 =IF(DB84="","",SUBSTITUTE(SUBSTITUTE(TRIM(MID(SUBSTITUTE(TRIM(DB84),"]",REPT("]",LEN(DB84))), 3*LEN(DB84)+1, LEN(DB84))),"]",""),"[",""))


DG84 =IF(DB84="","",SUBSTITUTE(SUBSTITUTE(TRIM(MID(SUBSTITUTE(TRIM(DB84),"]",REPT("]",LEN(DB84))), 4*LEN(DB84)+1, LEN(DB84))),"]",""),"[",""))


DH84 =IF(DB84="","",SUBSTITUTE(SUBSTITUTE(TRIM(MID(SUBSTITUTE(TRIM(DB84),"]",REPT("]",LEN(DB84))), 5*LEN(DB84)+1, LEN(DB84))),"]",""),"[",""))

If you have a better, more efficient way to extract the numbers out, I'd appreciate it.
 
Upvote 0
You're welcome. Glad to contribute. :)

If you have a better, more efficient way to extract the numbers out, I'd appreciate it.
What about like this?

NorthbyNorthwest.xlsm
DBDCDDDE
5ErrorsCode1Code2Code3
6[1105][2222][1238][3214]110522221238
7    
8[2222]2222  
Sheet1
Cell Formulas
RangeFormula
DB6:DB8DB6=IFERROR(IF([@Employee]="","",TRIM(CONCAT(tblDetails[@[Err1]:[Err23]],tblDetails[@[Err30]:[Err46]]))),"")
DC6:DC8DC6=IFERROR(INDEX(TEXTSPLIT([@Errors],{"[","]"}),2),"")
DD6:DD8DD6=IFERROR(INDEX(TEXTSPLIT([@Errors],{"[","]"}),4),"")
DE6:DE8DE6=IFERROR(INDEX(TEXTSPLIT([@Errors],{"[","]"}),6),"")
 
Upvote 0
You're welcome. Glad to contribute. :)


What about like this?

NorthbyNorthwest.xlsm
DBDCDDDE
5ErrorsCode1Code2Code3
6[1105][2222][1238][3214]110522221238
7    
8[2222]2222  
Sheet1
Cell Formulas
RangeFormula
DB6:DB8DB6=IFERROR(IF([@Employee]="","",TRIM(CONCAT(tblDetails[@[Err1]:[Err23]],tblDetails[@[Err30]:[Err46]]))),"")
DC6:DC8DC6=IFERROR(INDEX(TEXTSPLIT([@Errors],{"[","]"}),2),"")
DD6:DD8DD6=IFERROR(INDEX(TEXTSPLIT([@Errors],{"[","]"}),4),"")
DE6:DE8DE6=IFERROR(INDEX(TEXTSPLIT([@Errors],{"[","]"}),6),"")
Thanks again, Stephen. This forum has been a lifesaver for me. You guys really rock! All the Best.
 
Upvote 0
Thanks again, Stephen. This forum has been a lifesaver for me. You guys really rock! All the Best.
Sorry Peter. This post was originally intended for last reply I had from Stephen. But mistake gives me the opportunity to reiterate how grateful I am to all who answer this forum. You guys are phenomenal. All the Best!
 
Upvote 0

Forum statistics

Threads
1,224,815
Messages
6,181,136
Members
453,021
Latest member
Justyna P

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