Using column count to end of range

smartpat19

Board Regular
Joined
Sep 3, 2014
Messages
114
I have two dates and i am trying to create a dynamic date range based on those two dates.

in cell E5 is my starting date and E7 is my ending date. I have a formula to count the number of months between the dates in Y8="IFERROR(DATEDIF(E5,E7,"m"),0)"

I cannot get the end of range to copy my Edate formula. Or if there is a way to avoid using Y8's fromula that would be ideal.


Code:
Sub Update_Actuals()

Dim job As Worksheet
Dim column As Range
Dim columncount As Long




Set job = ThisWorkbook.Sheets("Job Cost Query")


job.Range("AF13").Formula = "=E5"


column = job.Range("Y8").Value


Set columncount = column + 14


Date = job.Range("AG13").Formula = "=EDATE(AF13,1)"
Date.Copy
Set daterange = job.Range(Cells(34.13), Cells(columncount, 13)).Paste


End Sub

Thank you ahead of time!
 

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.
From which initial cell to which final cell do you want to put the formula.
What are the references? That is, which row or column have data and based on that data put the formulas.
 
Upvote 0
From which initial cell to which final cell do you want to put the formula.
What are the references? That is, which row or column have data and based on that data put the formulas.

The final cell would be dynamic based on how many months between the beginning date (E5) and the final date (E7).

Inputs

E5 = 1/1/2019
E7 = 4/1/2019


Output, starting in AG13:
AG13AH13AI13AJ13
1/1/20192/1/20193/1/20194/1/2019

<tbody>
</tbody>

<tbody></tbody>
 
Upvote 0
Try this
The formula in Y8 is no longer necessary

Code:
Sub Update_Actuals()
  Dim i As Long
  For i = 0 To DateDiff("m", Range("E5"), Range("E7"))
    Cells(13, Columns("AG").Column + i) = WorksheetFunction.EDate(Range("E5"), i)
  Next
End Sub
 
Upvote 0
DanteAmor Thank you so much! this works great!

1.
I have additional formulas that I save at z31:Z78 that i want to copy under the dates which would be dynamic.

How can i reference the last column of the dates in row AG to allow for me to paste dynamically under the dates in AG?

2. Once I know the last column used I will want to add code at the beginning to remove the prior data before running the macro
 
Upvote 0
Try this

Code:
Sub Update_Actuals()
  Dim i As Long, lc As Long
[COLOR=#0000ff]  lc = Cells(13, Columns.Count).End(xlToLeft).Column  'last column[/COLOR]
  If lc < Columns("AG").Column Then lc = Columns("AG").Column
  Range(Cells(13, "AG"), Cells(13, lc)).ClearContents
  For i = 0 To DateDiff("m", Range("E5"), Range("E7"))
    Cells(13, Columns("AG").Column + i) = WorksheetFunction.EDate(Range("E5"), i)
  Next
End Sub
 
Upvote 0
This works perfectly!! thank you!

Is there an easy way to incorporate copying the formulas in Z31:Z78 to the if statement? They would be pasted under AG13.
 
Upvote 0
This works perfectly!! thank you!

Is there an easy way to incorporate copying the formulas in Z31:Z78 to the if statement? They would be pasted under AG13.


You just want to copy the cells in the Z31:Z78 under AG13, also under AH13 and so on?
 
Upvote 0
Try this

Code:
Sub Update_Actuals()
  Dim i As Long, lc As Long, lr As Long
  lc = Cells(13, Columns.Count).End(xlToLeft).Column  'last column
  lr = Range("AG" & Rows.Count).End(xlUp).Row         'last row
  If lc < Columns("AG").Column Then lc = Columns("AG").Column
  If lr < 13 Then lr = 13
  Range(Cells(13, "AG"), Cells([COLOR=#0000ff]lr, lc[/COLOR])).ClearContents
  For i = 0 To DateDiff("m", Range("E5"), Range("E7"))
    Cells(13, Columns("AG").Column + i) = WorksheetFunction.EDate(Range("E5"), i)
    Range("Z31:Z78").Copy Cells([COLOR=#ff0000]14[/COLOR], Columns("AG").Column + i)
  Next
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,482
Messages
6,113,916
Members
448,533
Latest member
thietbibeboiwasaco

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