#Value fix

Justplainj

New Member
Joined
Apr 15, 2021
Messages
13
Office Version
  1. 365
Platform
  1. Windows
Hi All,

Using office 365 dekstop.

I am sure this is a quick and easy fix for some but for some reason I cannot figure it out.
Tried searching other posts but no fix is unique to my problem.

I am having a #VALUE error can cannot find a quick way to fix it.
The reason it happens is because: Column A I have a value that is extracted from a reporting program which is read as example, 22 325.00 . It has a space after the first 22 and a space at the end due to custom formatting applied by the reporting program which the author of the program cannot seem to fix.
Column B I multiply the value in column A by a tax i.e. =A2*1.15 to add 15% tax.

I have tried the following in column A to try and change the formatting.
Removing spaces with Find & Replace function.
Using trim(), value() functions
Formatting to number formatting
Formatting to custom formatting.

The space at the end after the .00 never seems to go away
I am resorting to selecting the cell, removing the space at the end manually for each cell.

Problem, I have over 600k cells.

Is there any other quick way to solve this?
Having to do this every time a new report is drawn is a nightmare.

Thank you,
 

Excel Facts

Excel motto
Not everything I do at work revolves around Excel. Only the fun parts.

Justplainj

New Member
Joined
Apr 15, 2021
Messages
13
Office Version
  1. 365
Platform
  1. Windows
Hi,

If it helps the custom formatting that excel states is applied is the following.
_(* #,##0_);_(* (#,##0);_(* "-"??_);_(@_)
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
60,189
Office Version
  1. 365
Platform
  1. Windows
If you put this in an empty cell what does it return
Excel Formula:
=CODE(RIGHT(A2))
 

Justplainj

New Member
Joined
Apr 15, 2021
Messages
13
Office Version
  1. 365
Platform
  1. Windows
HI,

I have done it for multiple cells and all return 160
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
60,189
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

In that case try running this
VBA Code:
Sub justplainj()
   Range("A:A").Replace Chr(160), "", xlPart, , , , False, False
End Sub
Or use this formula
Excel Formula:
=SUBSTITUTE(SUBSTITUTE(A2,CHAR(160),"")," ","")*1.15
 
Solution

Justplainj

New Member
Joined
Apr 15, 2021
Messages
13
Office Version
  1. 365
Platform
  1. Windows
Hi Fluff,

Thank you for this.
I opted for the VBA code which solved it immediately.
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
60,189
Office Version
  1. 365
Platform
  1. Windows
You're welcome & thanks for the feedback.
 

Forum statistics

Threads
1,136,864
Messages
5,678,212
Members
419,751
Latest member
richkings

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