combine two cells average - vba

koloal

New Member
Joined
Sep 14, 2011
Messages
6
Hi everyone,
I want with vba to calculate the new average from the values of two cells but these values are not "equal weighted".
cell A1
has the : = (23+27+34)/3
cell A2
has the : =(45+23+34+42+36)/5
These are prices that I have entered manually some time ago and I calculated their average ( /3 and /5 )
I need the vba to create in a cell the new average:
= (23+27+34+45+23+34+42+36)/8
Also how do I find (vba?) the number of the prices that exist in these cells ( 3 and 5 numbers) - this is required for calc the average .

Thanks
Alexander
Hope I was clear but English isn't my native language
 

Excel Facts

Back into an answer in Excel
Use Data, What-If Analysis, Goal Seek to find the correct input cell value to reach a desired result
Welcome to the board.

Are there a lot of these combinations or just the two mentioned?
 
Upvote 0
This appears to do the job for the case outlined in the op.

If there are more, we'd have to wrap it in some sort of loop.

Code:
Sub combinesums()
    Dim newForm As String, fdiv As Long
    Set src = Range("A1:A2")
    Set dst = Range("A3")
    For Each c In src.Cells
        f = c.Formula
        fdiv = fdiv + Split(f, "/")(1)
        fnum = Replace(Mid(Split(f, "/")(0), 3, 255), ")", "")
        newForm = newForm & "+" & fnum
    Next
    dst.Formula = "=(" & newForm & ")/" & fdiv
End Sub
 
Upvote 0
There are 2-5 cells with numbers that I want to get their average but I can modify the code for the 2 cells that I asked for in my first post.
Thanks
 
Upvote 0
There are 2-5 cells with numbers that I want to get their average but I can modify the code for the 2 cells that I asked for in my first post.
Thanks

If you need to combine more than 2 cells, you can modify the range defintion of src. If you need to change the location of the output, change dst.
 
Upvote 0
A small modification if a cell contains only one number and if you are hidding some rows:

Code:
Dim newForm As String, fdiv As Long
    Set src = Range("A1:A2")
    Set dst = Range("A3")
    
    For Each cell In src.Cells
        If cell.Rows.Hidden = False Then
            If cell.Value <> 0 Then
                f = cell.Formula
                If InStr(f, "/") > 0 Then
                    fdiv = fdiv + Split(f, "/")(1) * 1
                    fnum = Replace(Mid(Split(f, "/")(0), 3, 255), ")", "")
                    newForm = newForm & "+" & fnum
                Else
                    fdiv = fdiv + 1
                    fnum = Right(f, Len(f) - InStr(f, "="))
                    newForm = newForm & "+" & fnum
                End If
                dst.Formula = "=(" & newForm & ")/" & fdiv
            End If
        End If
    Next
 
Upvote 0

Forum statistics

Threads
1,224,586
Messages
6,179,726
Members
452,939
Latest member
WCrawford

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