Working with Roman Numerals

Written by Allen Wyatt (last updated September 18, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003


Excel includes a worksheet function that allows you to convert a number to Roman numerals. (Hmmm. Let's see... I was born in MCMLVI. Dang! I'm a classic!) The simplest way to use the Roman numerals is as follows:

=ROMAN(123)

All you need to do, obviously, is replace 123 with the number you want converted. You can use any number between 1 and 3999. (Romans apparently never worked with numbers outside this range.)

You can also, if desired, use a second argument to indicate how the resulting Roman numerals should be put together. The different arguments you can use are 0 through 4, with 0 being the default. An argument of 0 returns Roman numerals in the classic form, and 4 returns an extremely simplified Roman numeral. Values between 0 and 4 return progressively more simplified versions. The simplification of Roman numerals typically only comes into play when dealing with larger numbers. For instance, the following shows the various levels of simplification of the number 1999:

Formula Result
=ROMAN(1999,0) MCMXCIX
=ROMAN(1999,1) MLMVLIV
=ROMAN(1999,2) MXMIX
=ROMAN(1999,3) MVMIV
=ROMAN(1999,4) MIM

You should note that the ROMAN function returns a text value, and you therefore cannot use the result in any sort of calculation—as far as Excel is concerned, it is no longer a number.

Older versions of Excel (including Excel 2003) do not include a function to convert Roman numerals back to Arabic numbers. If you want to use a formulaic approach to do the conversion, you can try this:

=MATCH(A1,INDEX(ROMAN(ROW(INDIRECT("1:4000"))),0),0)

This presumes that the Roman numerals are in cell A1. If you prefer, you can create your own user-defined function to do the conversion to Arabic:

Public Function UnRoman(RomanNumber As String) As Integer
    Dim MySum As Integer
    Dim MyDeduct As Integer
    Dim MyWord As String
    Dim L As String
    Dim WordLength As Integer
    Dim i As Integer
    Dim MyArray() As Integer

    MySum = 0
    MyDeduct = 0
    MyWord = UCase(RomanNumber)
    WordLength = Len(MyWord)
    ReDim MyArray(WordLength + 1)

    For i = 1 To WordLength
        L = Mid(MyWord, i, 1)
        MyArray(i) = Switch(L = "I", 1, L = "V", 5, _
          L = "X", 10, L = "L", 50, L = "C", 100, _
          L = "D", 500, L = "M", 1000)
        MySum = MySum + MyArray(i)
    Next
    For i = 1 To WordLength - 1
        If MyArray(i) < MyArray(i + 1) Then
            MyDeduct = MyDeduct + MyArray(i)
        End If
    Next
    'Now deduct twice the value of the subtraction numbers
    UnRoman = MySum - 2 * MyDeduct
End Function

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (1956) applies to Microsoft Excel 97, 2000, 2002, and 2003.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Splitting a Table

Table getting too long? Need to move part of a table to somewhere else in your document? You can easily split an existing ...

Discover More

Getting the Name of the Worksheet Into a Cell

Excel allows you to change the names assigned to the worksheets in a workbook. If you want to have those names appear in ...

Discover More

Cleaning Up Text in a Macro

Need to remove extraneous characters from a text string? VBA makes it easy through the CleanString method, described in ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (menu)

Selecting Random Names

Got a tone of names from which you need to select a few random names? There are several ways you can extract what you ...

Discover More

Using the WEEKNUM Function

Need to know which week of the year a particular date falls within? Excel provides the WEEKNUM function so you can easily ...

Discover More

Converting to Octal

If you need to do some work in the base-8 numbering system (octal), you'll love two worksheet functions provided by Excel ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two more than 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.