creating automated income statement, want to add dynamic monthly column to AVERAGE and SUM

pawest

Board Regular
Joined
Jun 27, 2011
Messages
105
Hi VBA masters,
I'm creating an automated daily income statement with currency rates, cash balances, expenses, etc. I would like to add a monthly column that's dynamic and uses VBA's ".Formula" tool to add functions and perform calculations on the daily values. I'm having trouble using the .End(xlToRight) technique to make it dynamic. Here are some pieces of what I have so far:

PHP:
Dim homecell as object
Dim CCYrange As Object 

Set homeCell = Range("D5")
Set CCYrange = Range(Range("D5"), Range("D5").End(xlToRight))

homecell.Offset(4, 10).Formula = "=AVERAGE(" & CCYrange & ")"

When I run the above code, I get a "Run-time error '13': Type mismatch" ... when I hardcode the range, such as "=AVERAGE(D5:G5)", it works. Any help on this issue would be great!

Thanks!
 

Excel Facts

How to total the visible cells?
From the first blank cell below a filtered data set, press Alt+=. Instead of SUM, you will get SUBTOTAL(9,)
Try:-
Rich (BB code):
homecell.Offset(4, 10).Formula = "=AVERAGE(" & CCYrange.Address & ")"  

 
Upvote 0
Hey MickG,
I appreciate the quick response. No more errors! But it semi-works. It only works if there has been data previously entered in a cell in the same row ahead of the beginning cell ("D5" in this case). If data was not previously in a cell ahead of the beginning cell then it locks and selects to the spreadsheet's last column, for example: when the code is run, the monthly average cell equals this "=AVERAGE($D$5:$XFD$5)".

Unfortunately for my income statement spreadsheet, having previously entered data into the spreadsheet will never be the case. Unless you or anyone else can think of a way to use the .address technique, I might have to go with and offset - 1 type of a deal.

Any other recommendations?

Thanks for your help!
 
Upvote 0
Assuming you have data in "D5" ths might help !!
Code:
Set CCYrange = Range(Range("D5"), Cells(5, Columns.count).End(xlToLeft))
 
Upvote 0
MickG,
Almost got it! Is there any way to do something like :

Set CCYrange = Range(Range("D5"), (Cells(5, Columns.count).End(xlToLeft)-1)) ?

Thanks!
</pre>
 
Upvote 0
I'm not quite sure what you are trying to do !!
Do you only want to run the formula bit of the code if there is some data in at least one of the cells from "D5" on, or something else.???
 
Upvote 0
I think the problem that I'm running into is that for the first day of the month, it doesn't select the appropriate range. Once there is data in the first day of the month (the first column of data or column D in my case) and data for additional days worth of data, the macro works. However, when using your suggestion of Columns.count, it includes everything up to the up to the last column... in other word it selects the monthly column which is the last column. As you can see, a formula in a cell doesn't work if the selection it references includes the active cell.

I think I might have to layer this with If-Then statements and I'm not particularly advanced with VBA but I might know enough to say If it's the first day of the month then print data, if it's the X + 1 day of the month then include the dynamic selections... if that makes sense. I'd rather keep it more simple than that but I'll keep working at it.
 
Upvote 0
MickG,
Thanks for your help. I wouldn't have been to accomplish my project without your .address suggestion! Here's what I ended up doing (I will try to optimize it a bit further since I'm still in the testing stage):

HTML:
Dim CCYcell as Range

Set CCYcell = Range("D5")

        If CCYcell.Offset(0, 1).Value = 0 Then
            CCYcell.Select
        Else
            Range(CCYcell, CCYcell.End(xlToRight)).Select
        End If
        .Offset(4, 7).Formula = "=AVERAGE(" & Selection.Address & ")"

Thanks!
 
Upvote 0

Forum statistics

Threads
1,213,495
Messages
6,113,992
Members
448,538
Latest member
alex78

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