Shuffle values to always equal another cell but allow individual cell modification.

Strugglin Exceller

New Member
Joined
Mar 9, 2021
Messages
13
Office Version
  1. 365
Platform
  1. Windows
I have a spreadsheet that is to calculate door panels. There are 4 panels on the door and they need to be sized so if the height of the door changes, they total values of the panels will never exceed the height of the door.

However, I want to be able to adjust 1, 2 or 3 of any of the panels manually and if I do, the ones I don't define will automatically be equal. Here is a picture of what i'm trying to set up. I have no formulas in any of the cells. but you can see in the picture what I'm trying to do. I would prefer this be done with formulas. However, I'm guessing VBA would be better and that's ok. Your help is very much appreciated.

1709915291535.png
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Copy and paste this macro into the worksheet code module. Do the following: right click the tab name for your sheet and click 'View Code'. Paste the macro into the empty code window that opens up. Close the code window to return to your sheet. Enter a value in B4:B7 and press the ENTER key.
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.CountLarge > 1 Then Exit Sub
    If Intersect(Target, Range("B4:B7")) Is Nothing Then Exit Sub
    Application.ScreenUpdating = False
    Dim height As Long, rng As Range, cntBlanks As Long, cnt As Long, total As Long
    height = Range("B2").Value
    cntBlanks = Range("B4:B7").SpecialCells(xlCellTypeBlanks).Count
    cnt = WorksheetFunction.CountA(Range("B4:B7"))
    total = WorksheetFunction.Sum(Range("B4:B7"))
    For Each rng In Range("B4:B7")
        If rng <> "" Then
            rng.Offset(, 1) = rng
        Else
            rng.Offset(, 1) = (height - total) / cntBlanks
        End If
    Next rng
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Solution
Tidied up a bit:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.CountLarge > 1 Then Exit Sub
    If Intersect(Target, Range("B4:B7")) Is Nothing Then Exit Sub
    Application.ScreenUpdating = False
    Dim height As Long, rng As Range, cntBlanks As Long, total As Long
    height = Range("B2").Value
    cntBlanks = Range("B4:B7").SpecialCells(xlCellTypeBlanks).Count
    total = WorksheetFunction.Sum(Range("B4:B7"))
    For Each rng In Range("B4:B7")
        If rng <> "" Then
            rng.Offset(, 1) = rng
        Else
            rng.Offset(, 1) = (height - total) / cntBlanks
        End If
    Next rng
    Application.ScreenUpdating = True
End Sub
 
Upvote 0
Copy and paste this macro into the worksheet code module. Do the following: right click the tab name for your sheet and click 'View Code'. Paste the macro into the empty code window that opens up. Close the code window to return to your sheet. Enter a value in B4:B7 and press the ENTER key.
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.CountLarge > 1 Then Exit Sub
    If Intersect(Target, Range("B4:B7")) Is Nothing Then Exit Sub
    Application.ScreenUpdating = False
    Dim height As Long, rng As Range, cntBlanks As Long, cnt As Long, total As Long
    height = Range("B2").Value
    cntBlanks = Range("B4:B7").SpecialCells(xlCellTypeBlanks).Count
    cnt = WorksheetFunction.CountA(Range("B4:B7"))
    total = WorksheetFunction.Sum(Range("B4:B7"))
    For Each rng In Range("B4:B7")
        If rng <> "" Then
            rng.Offset(, 1) = rng
        Else
            rng.Offset(, 1) = (height - total) / cntBlanks
        End If
    Next rng
    Application.ScreenUpdating = True
End Sub
This worked! thank you
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,182
Members
453,020
Latest member
Mohamed Magdi Tawfiq Emam

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top