Written by Allen Wyatt (last updated May 4, 2024)
This tip applies to Excel 97, 2000, 2002, and 2003
Jim described a situation where he has a list of employee names and their salaries. He wants to determine who the five highest-paid employees are. He uses the LARGE function to identify the five largest salaries, and then tries to use VLOOKUP to return the names belonging to those salaries. This works fine unless there are duplicates in the top five salaries (people get paid the same salary). If there are, then VLOOKUP only returns the name of the first employee at that salary.
To return all the proper names, there are a couple things you could do. One method would be to bypass using a formula altogether. Instead, you could use the AutoFilter feature in Excel:

Figure 1. The Top 10 AutoFilter dialog box.
When you follow these steps, you may actually end up with more than five records visible, particularly if there are ties in the employee salaries. The filter identifies the top five salaries and then displays all the records with salaries matching those.
If you don't want to use the AutoFilter, another option is to simply make sure that there is something unique about each of the records in your employee list. For instance, if the employee names are in column B and the salaries are in column C, then you could use the following formula in column A to make each record unique:
=C2+ROW()/100000000
This will add the row number divided by 100,000,000 and will make a unique value. If you have (for example) identical salaries of 98,765.43 in rows 2 and 49 in column A they will be:
98765.43000002 98765.43000049
The large number (100,000,000) is so that if you had an identical number in row 65536, you would get:
98765.43065536
And even in this case the rounded value to 2 decimal places would still be the real number. If the LARGE and VLOOKUP are done with the "non-unique" values in column A, then you will return the largest salaries (and their associated people), based on the person's position within the list.
A third approach is to use the RANK and COUNTIF functions to return a unique "ranking" for each value in the list of salaries. If the salaries are in the range B1:B50, enter the following in cell C1 and copy it down the range:
=RANK(B1,$B$1:$B$50)+COUNTIF($B$1:B1,B1)-1
You can now use INDEX on the ranking values to return the name associated with each salary.
Finally, a fourth approach is to create a macro that can return the desired information. There are many ways that a macro could be implemented; the following is just one of them:
Function VLIndex(vValue, rngAll As Range, _
iCol As Integer, lIndex As Long)
Dim x As Long
Dim lCount As Long
Dim vArray() As Variant
Dim rng As Range
On Error GoTo errhandler
Set rng = Intersect(rngAll, rngAll.Columns(1))
ReDim vArray(1 To rng.Rows.Count)
lCount = 0
For x = 1 To rng.Rows.Count
If rng.Cells(x).Value = vValue Then
lCount = lCount + 1
vArray(lCount) = rng.Cells(x).Offset(0, iCol).Value
End If
Next x
ReDim Preserve vArray(1 To lCount)
If lCount = 0 Then
VLIndex = CVErr(xlErrNA)
ElseIf lIndex > lCount Then
VLIndex = CVErr(xlErrNum)
Else
VLIndex = vArray(lIndex)
End If
errhandler:
If Err.Number <> 0 Then VLIndex = CVErr(xlErrValue)
End Function
The parameters passed to this user-defined function are the value, the range of cells to lookup in, the "offset" from this range for the lookup (the number of columns to the right is positive, to the left is negative) and the number of the duplicate (1 is first value, 2 the second, and so on).
To use it, for example's sake, assume A1:B1 contain column headers, A2:A100 contains the salaries, and B2:B100 contains the employee names. In cell E2 you can enter the following to determine the largest salary in the table:
=LARGE($A$2:$A$100,ROW()-1)
In cell F2 you can enter the following formula to determine if the row has any duplicates and keep track of the current "value" of that duplicate:
=IF(E2=E1,1+F1,1)
In cell G2 you can use the following formula, which invokes the user-defined function:
=VLIndex(E2,$A$2:$A$100,1,F2)
Copy cells E2:G2 to E3:G6, and you will have (in column G) the names of the employees with the five largest salaries.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3077) applies to Microsoft Excel 97, 2000, 2002, and 2003.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel Data Analysis and Business Modeling today!
Need to calculate the date that is a certain number of workdays in the future? You can do so using a couple of different ...
Discover MoreOne of the most useful function in Excel is VLOOKUP. One thing it won't do, however, is allow you to lookup information ...
Discover MoreThe VLOOKUP function, like other lookup functions in Excel, is not case sensitive. In other words, it doesn't matter ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2025-10-25 07:47:59
jamies
The parts, or all of the following script code may be of use -
but note that
Application.ExecuteExcel4Macro("Get.ToolBar(7,""Ribbon"")")
will probably need the setting options to allow the excel4 macro mode, and
acceptance of the security risks associated with that permission.
however the excel4 macros (AFAIK) well remember allow analysis of data being entered into a cell,
rather than what excel considers the entry as a whole was - e.g 2/3/5 being a date to Excel,
and 00045789e-3 or 000457.89 being float numbers rather than text strings
Sub windowfix2016()
' For excel 2016 - Change the window size, range & ribbon status .....
' only for office 2016 but if 2013 also needs dealing with that will be test for version 15
If Application.Version < 16 Then
nn = ""
Else
' This is to be called by the macros that open a subsiduary worksheet
' use a Global setting for all window realignments - this can be set according to the users wishes
' After doing the active .screen .workbook & .worksheet it will then set the ribbon as requested
Dim iRibbon As Integer ' 0 = none, 1 = Menu, 2 = Commands too, 3= Leave as is
Dim iStartX As Integer
Dim iStartY As Integer
Dim iDesiredWidth As Integer
Dim iDesiredHeight As Integer
Dim iviewrange As String
iRibbon = 1 ' 0 = none, 1 = Menu, 2 = Commands too, 3= Leave as is
iStartX = 50 ' Distance from left
iStartY = 25 ' Distance from top
iDesiredWidth = 600
iDesiredHeight = 500
iviewrange = "A1:G35" ' Note the columns are what matters
With Application
.WindowState = xlMaximized
iMaxWidth = Application.Width ' max end is the window end in fullscreen
iMaxHeight = Application.Height
iMaxWidth = iMaxWidth - iStartX ' Adjust window for starting point
iMaxHeight = iMaxHeight - iStartY
If iDesiredWidth > iMaxWidth Then iDesiredWidth = iMaxWidth
If iDesiredHeight > iMaxHeight Then iDesiredHeight = iMaxHeight
.WindowState = xlNormal ' so now set the window
.Top = iStartY
.Left = iStartX
.Width = iDesiredWidth
.Height = iDesiredHeight
End With
' and now fit the selected range into that window
ActiveSheet.Range(iviewrange).Select
ActiveWindow.Zoom = True
' Now for the ribbon setting
If iRibbon = 3 Then
iRibbon = 3 ' do nothing
Else
' In Word:
' ActiveWindow.ToggleRibbon has the same effect as double-clicking on a ribbon tab.
' In Excel: this swaps the state to lose the menu and ribbon, or reinstate it
' RibbonHeight <100 (=73?) seems to mean it is hidden, or in no commands mode
' RibbonHeight >100 (well >73?) seems to mean it is not hidden, and is also showing commands
' (hidden you get full-screen usage, with tabs showing
' Restore sets it to windowed without the menu
Dim iribbonheight As Long
Dim iribbonstate As Long
iribbonstate = Application.ExecuteExcel4Macro("Get.ToolBar(7,""Ribbon"")")
iribbonheight = CommandBars("Ribbon").Controls(1).Height
' So - switch ribbon on/off state
' Off = full screen filename at top and tabs at bottom
' on is ribbon with, or without commands - as determined by the CommanBars.ExecuteMSO MinimizeRibbon
' But Show False hides all the surround of the page and full-window's it.
' need to use the setting for "show tabs" rather than "Autohide" or "Show tabs and Commands"
If iRibbon = 0 Then
Application.ExecuteExcel4Macro "Show.ToolBar(""Ribbon"", False)" ' 0 = no ribbon
Else
Application.ExecuteExcel4Macro "Show.ToolBar(""Ribbon"", True)" ' 1 or 2 = show ribbon
End If
ribbonheight = CommandBars("Ribbon").Controls(1).Height
ribbonstate = (CommandBars("Ribbon").Controls(1).Height < 100) ' under 100 means no commands
'Hide Ribbon if it is on the screen in 2010-2016
If ribbonstate = vbFalse And iRibbon = 1 Then CommandBars.ExecuteMso "MinimizeRibbon"
If ribbonstate = vbTrue And iRibbon = 2 Then CommandBars.ExecuteMso "MinimizeRibbon"
' yes - CommandBars.ExecuteMso "MinimizeRibbon seems to toggle minimize to max and back
End If
End If
End Sub
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments