Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Determining Combinations to Make a Total.
Written by Allen Wyatt (last updated April 15, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Suppose you have a worksheet with three columns of data. The first column has in sequential order each letter of the alphabet, A through Z. The second column contains a number of occurrences that correlates with the letter in the alphabet. The third column contains a number of hours that correlates with the letter in the alphabet.
What if you want to distribute, as evenly as possible, a combination of the alphabet letters into four groups based on the third column (hours)? For example, if the sum of all the hours for each letter of the alphabet is 4,000 hours, you want to come up with a combination that would segregate the alphabet so that each one of the four groups would have around 1,000 hours per group.
This is actually a well-known problem in the field of discrete mathematics. A variety of algorithms have been developed to provide solutions, and there are certain programming languages (such as LISP) that greatly facilitate creating tree structures that can "search" for optimal solutions.
In this case, however, a simple approach is best, and that involves using a macro. Let's assume that you have your data in columns A through C. The following macro will analyze the range you specify and return a combination of values that fulfill your requirements.
Function DoDist(sRaw As Range, _ iTCol As Integer, _ iBuckets As Integer, _ iWanted As Integer, _ iRetCol As Integer) As String Dim lGTotal As Long Dim lPerBucket As Long Dim lCells() As Long Dim sRet() As String Dim lBk() As Long Dim sBk() As String Dim lTemp As Long Dim sTemp As String Dim J As Integer Dim K As Integer Dim L As Integer Application.Volatile ReDim lCells(sRaw.Rows.Count) ReDim sRet(sRaw.Rows.Count) ReDim lBk(iBuckets) ReDim sBk(iBuckets) lGTotal = 0 For J = 1 To sRaw.Rows.Count lCells(J) = sRaw(J, iTCol) lGTotal = lGTotal + lCells(J) sRet(J) = sRaw(J, iRetCol) Next J For J = 1 To sRaw.Rows.Count - 1 For K = J + 1 To sRaw.Rows.Count If lCells(J) < lCells(K) Then lTemp = lCells(J) lCells(J) = lCells(K) lCells(K) = lTemp sTemp = sRet(J) sRet(J) = sRet(K) sRet(K) = sTemp End If Next K Next J lPerBucket = lGTotal / iBuckets For J = 1 To sRaw.Rows.Count L = iBuckets For K = iBuckets To 1 Step -1 If lBk(K) <= lBk(L) Then L = K Next K lBk(L) = lBk(L) + lCells(J) sBk(L) = sBk(L) & sRet(J) & ", " Next J For J = 1 To iBuckets If Right(sBk(J), 2) = ", " Then sBk(J) = Left(sBk(J), Len(sBk(J)) - 2) End If sBk(J) = sBk(J) & " (" & lBk(J) & ")" Next J DoDist = sBk(iWanted) End Function
Notice that this function is passed five parameters. The first is the range that you want evaluated, the second is the offset of the column within that range that should be totaled, the third is the number of "buckets" you want to use in the evaluation, the fourth is the number of the bucket that you want to return, and the fifth is the offset of the column (in the specified range) that contains the values you want returned.
What the macro does is to grab all the values in the column you want totaled, and then sort them in descending order. These values, from largest to smallest, are then distributed among however many "buckets" you specified that there should be. The number is always added to the bucket that contains the smallest total. The string that is returned by the function represents the return values (whatever is in each cell of the column specified by the fifth parameter) and the total of the bucket.
For instance, if you wanted to evaluate the range A1:C:26, you wanted the distribution to be based on the values in the third column of the range (column C), you wanted there to be four buckets in the analysis, you wanted the third bucket returned, and you wanted to have the function return whatever is in column A of the range, then you would use the following to call the function:
=DoDist(A1:C26,3,4,3,1)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12234) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Determining Combinations to Make a Total.
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 2013 Data Analysis and Business Modeling today!
You can easily use the COMBIN worksheet function to determine the number of combinations that can be made from a given ...
Discover MoreThe filtering capabilities of Excel are excellent, providing you with great control over which records in a worksheet are ...
Discover MoreNeed to get at the next-to-last value in a column, regardless of how many cells are used within that column? This tip ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-04-18 09:36:07
J. Woolley
@Dave S
Your version is correct in a VBA statement.
The Tip's version is correct in a cell formula.
2023-04-17 05:34:16
Dave S
I think the call statement should to be
=DoDist(Range("A1:C26"),3,4,3,1)
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