Written by Allen Wyatt (last updated November 22, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Aakhil receives his bank statement as a PDF file each month. When he converts it to an Excel file, the numbers end up in the format 5,000CR and 257DB. Aakhil needs to convert these obviously text values into actual numbers, with the CR amounts being negative and the DB amounts being positive.
A formula can be used to do the conversion from a text to a numeric value, and there are several different formulaic approaches that could be used. Here's a very simple one, assuming your text value is in cell A1:
=LEFT(A1,LEN(A1)-2)*IF(RIGHT(A1,2)="CR",-1,1)
This formula assumes that the text value ends in either CR or DB, as Aakhil seems to indicate. The formula uses the LEFT function to return everything in the cell except the last two characters, and then multiplies that by either -1 (if the last two characters are CR) or 1. The multiplication ensures that what is returned by the formula is a numeric value instead of a text value.
Again, the formula assumes that the ONLY last two characters are CR or DB. If they might be something else, or if there might not be any trailing characters at all, then the following formula would be a better approach:
=LEFT(A1,LEN(A1)-2)*IF(RIGHT(A1,2)="DB",1,IF(RIGHT(A1,2)="CR",-1,0))
This version checks for CR and DB and multiplies accordingly. If the last two characters are anything else, then it is multiplied by 0. You can then check all the 0 results and manually adjust them according to your needs.
If you are using Excel 2021 or the version of Excel with Office 365, then you could build a robust formula in the following manner:
=LET(s,RIGHT(A1,2),n,LEFT(A1,LEN(A1)-2),IF(s="DB",--n,IF(s="CR",-n,"PROBLEM")))
The formula uses the LET function to assign the right two characters of A1 to the s variable and the rest of the characters to the n variable. If s is equal to "DB," then a positive (--) version of n is returned; if s is equal to "CR," then a negative version of n is returned; if s is equal to anything else, then the text "PROBLEM" is returned. This makes it very easy to identify any problem areas you need to check.
If you need to do the conversion quite often, then you might find it helpful to use a macro. The following will evaluate any selected cells and properly convert them as long as they end in either DB or CR:
Sub FixCRDB() Dim c As Range Dim sRaw As String Dim sNum As String For Each c In Selection sRaw = Trim(c.Value) If Len(sRaw) > 2 Then sNum = Left(sRaw, (Len(sRaw) - 2)) If IsNumeric(sNum) Then Select Case Right(sRaw, 2) Case "CR" c.Value = -CDbl(sNum) Case "DB" c.Value = CDbl(sNum) End Select End If End If Next c End Sub
Again, select the cells you want to convert and run the macro. Those ending in CR or DB are converted to numeric values—either positive or negative, as Aakhil desired—and anything else is ignored.
Another way to handle reading the PDF and doing the conversion on a regular basis is to use Power Query. How to actually set that up is beyond the scope of this tip, though, as the format of the PDF itself is critical to doing the transformation. Understand, however, that you could set up the query once and reuse it, month after month, to import your bank statement into Excel.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13940) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Do you need to know how many precedents or dependents there are on a worksheet? You could count them manually, or you ...
Discover MoreWhen Excel performs a calculation, the results you see in an unformatted cell may cause a bit of concern. This tip ...
Discover MoreNeed to know a count of unique values in a range of cells? There are a couple of ways you can tackle the problem.
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments