<<Convert Excel Spreadsheets to Web Pages | Trading Software That Operates Within Excel | Convert Excel, Access & Other Databases | Merge Excel Files>>
Ozgrid, Experts in Microsoft Excel Spreadsheets

Excel Formula Function - Convert Imported Negative Numbers

| | Information Helpful? Why Not Donate.

TRY OUT: Smart-VBA | Code-VBA | Analyzer-XL | Downloader-XL | Trader-XL| More Free Downloads.. Best Value: Finance Templates Bundle

SEE ALSO: Text to Numbers

Current Special! Complete Excel Excel Training Course for Excel 97 - Excel 2003, only $145.00. $59.95 Instant Buy/Download,30 Day Money Back Guarantee & Free Excel Help for LIFE!

Got any Excel Questions? Free Excel Help

Mirror Negatives

Anyone that has worked with imported numbers in Excel will often be left with the problem of imported negative numbers that have the negative sign to the right of the number.  These are referred to as mirror negatives. This means Excel will not see your numbers as negative numbers and to make matters worse, it won't even see them as valid numbers.

SAP is one such program that does this with negative numbers, e.g 200- instead of -200

Let's say you have a great long list of numbers you have just imported and some of them are those so-called negative numbers (mirror negatives). Your job is to convert these to valid negatives that Excel will recognize. For the purpose of the exercise we will make the range A1:A100.  In cell B1 enter this formula;

=SUBSTITUTE(IF(RIGHT(TRIM(A1))="-",RIGHT(TRIM(A1))&A1,A1),"-","",2)+0

Copy this down as many cells as needed and then copy them and select cell A1 and go to Edit>PasteSpecial-Values , directly over the top of the originals.

To give you an idea on how the formula works enter this part of it in any cell where A1 has the text 200-

=RIGHT(TRIM(A1),1)&A1

You will end up with; -200- The TRIM function simply ensure there are no space characters in the cell. As we end up with -200- we next need to remove the second occurrence of the negative sign. This is what; the SUBSTITUTE function is doing. We have told it to substitute the second occurrence of "-" with "" (empty text). Now, the result returned is actually text (as that is what the SUBSTITUTE function returns) so we simply use +0 and Excel will convert it to a valid number.

If doing this is a common task you should consider a macro to make the job easier. Below is one that will do the task at hand in no time.  It has been optimized for speed.

Sub ConvertMirrorNegatives()
Dim rCell As Range
Dim rRange As Range
Dim lCount As Long
Dim lLoop As Long If Selection.Cells.Count = 1 Then
  MsgBox "Please select the range to convert", vbInformation
  Exit Sub
End If On Error Resume Next
Set rRange = Selection.SpecialCells(xlCellTypeConstants, xlTextValues) If rRange Is Nothing Then
   MsgBox "No mirror negatives found", vbInformation
   On Error GoTo 0
   Exit Sub
End IflCount = WorksheetFunction.CountIf(Selection, "*-")
Set rCell = Selection.Cells(1, 1) For lLoop = 1 To lCount
        Set rCell = rRange.Find(What:="*-", After:=rCell, _
                    LookIn:=xlValues, LookAt:=xlPart, _
                    SearchOrder:=xlByRows, SearchDirection:= _
                    xlNext, MatchCase:=False)
               
        rCell.Replace What:="-", Replacement:=""
        rCell = rCell * -1
  Next lLoop
On Error GoTo 0
End Sub

To use this macro, go to Tools>Macro>Visual Basic Editor (Alt+F11) and then to Insert>Module and paste in the code above. Click the top right X to return to Excel and go to Tools>Macro>Macros select ConvertMirrorNegatives then click Options and assign a shortcut key.

Excel Dashboard Reports & Excel Dashboard Charts 50% Off Become an ExcelUser Affiliate & Earn Money

Special! Free Choice of Complete Excel Training Course OR Excel Add-ins Collection on all purchases totaling over $64.00. ALLpurchases totaling over $150.00 gets you BOTH! Purchases MUST be made via this site. Send payment proof to [email protected] 31 days after purchase date.


Instant Download and Money Back Guarantee on Most Software

Try out:Analyzer XL |Downloader XL |Smart VBA |Trader XL Pro (best value) |ConsoXL | MergeXL | O2OLAP for Excel | MORE>>

Excel Trader PackageTechnical Analysis in Excel With $139.00 of FREE software!

Microsoft � and Microsoft Excel � are registered trademarks of Microsoft Corporation. OzGrid is in no way associated with Microsoft

Some of our more popular products are below...
Convert Excel Spreadsheets To Webpages | Trading In Excel | Construction Estimators | Finance Templates & Add-ins Bundle | Code-VBA | Smart-VBA | Print-VBA | Excel Data Manipulation & Analysis | Convert MS Office Applications To...... | Analyzer Excel | Downloader Excel | MSSQL Migration Toolkit | Monte Carlo Add-in | Excel Costing Templates