Excel Old School Array Help

denzo36

Board Regular
Joined
Sep 22, 2019
Messages
149
Office Version
  1. 365
Platform
  1. Windows
Hi all, I should know this but for the life of me can't remember so apologies!

I've have a string that is of length 13 characters but should be 12 characters long. When my data is downloaded from the source I'm using, hidden characters are included but appear to placed at different positions in the string meaning what should be a 12 character string is becoming 13 character string.

I've managed to figure out how to identify where the hidden character is within the string but now need to bring the string back together minus this hidden character. I'd rather not use VBA for this but I think an array formula should do it, unfortunately as this is my work pc I only have Excel 2016 without dynamic arrays or the TEXTJOIN function which could do it pretty easily.

The formula I'm using in B2 is =CHAR(CODE(MID($A2,COLUMNS($C$1:C$1),1))) which is identifying the hidden character '?' in my string. As you can see from row 2 and row 3, '?' appears at the start of the string in row 2 but and the end of the string in row 3. I'd like to be able to concatenate columns B to N to only include characters that are not '?' so I was thinking some along the lines B2:N2<>"?" and extract the true from this

Anyone got an ideas?

1590056062338.png
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,682
Office Version
  1. 365
Platform
  1. Windows
See if this works (without the extra columns)

=CONCAT(IFERROR(--MID(A2,ROW($1:$13),1),"")

edit:- ignore that, I missed the 2016 requirement in your post, off to devise a new plan.
 

denzo36

Board Regular
Joined
Sep 22, 2019
Messages
149
Office Version
  1. 365
Platform
  1. Windows
Hi Jason, cheers for the reply but I haven't got office 365 on my work pc as mentioned in my post, I know my profile says I do but this is for my own personal pc!
 

jasonb75

Well-known Member
Joined
Dec 30, 2008
Messages
12,682
Office Version
  1. 365
Platform
  1. Windows
Try this one, array confirmed

=REPLACE(A2,MATCH(2,1/ISERROR(--MID(A2,ROW($1:$13),1))),1,"")

Note that this only works with a single hidden character in the string, more could be a problem.
 

denzo36

Board Regular
Joined
Sep 22, 2019
Messages
149
Office Version
  1. 365
Platform
  1. Windows
That's brilliant thanks a million Jason much appreciated!
 

Watch MrExcel Video

Forum statistics

Threads
1,130,218
Messages
5,640,952
Members
417,182
Latest member
mgcorreia

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
Top