Last row insert formulas

swingline

New Member
Joined
Oct 29, 2019
Messages
15
I need some help. I get a few reports like this on a weekly basis the largest one only containing about 150 rows and 26 columns. What I would like to do is use a macro to add a few things to the bottom of each sheet. Each sheet is dynamic in its number of rows and columns.

[TABLE="class: grid, width: 1260, align: center"]
<tbody>[TR]
[TD]123465[/TD]
[TD]30-Nov-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]3-Feb-2020[/TD]
[TD]20-Jan-2020[/TD]
[TD]30-Jun-2021[/TD]
[TD]30-Jun-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]4-Oct-2020[/TD]
[TD]27-Jun-2020[/TD]
[TD]27-Dec-2019[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]28-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]16-Jan-2020[/TD]
[TD]6-Dec-2019[/TD]
[TD]N/A[/TD]
[TD]31-Jan-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]20-Mar-2020[/TD]
[TD]27-Jun-2020[/TD]
[TD]27-Dec-2019[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]3-Jan-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]10-Jan-2019[/TD]
[TD]26-Apr-2020[/TD]
[TD]13-Dec-2020[/TD]
[TD]30-Sep-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]8-Jan-2020[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]31-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]17-Jun-2020[/TD]
[TD]23-Dec-2019[/TD]
[TD]N/A[/TD]
[TD]30-Jun-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]26-Jul-2018[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]29-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]17-Jun-2020[/TD]
[TD]11-Apr-2020[/TD]
[TD]7-Sep-2020[/TD]
[TD]31-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]23-Oct-2020[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]13-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]17-Jun-2020[/TD]
[TD]3-Jan-2020[/TD]
[TD]N/A[/TD]
[TD]29-Feb-2020[/TD]
[TD]N/A[/TD]
[TD]26-Dec-2019[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]18-Oct-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]23-Jan-2020[/TD]
[TD]N/A[/TD]
[TD]7-Sep-2020[/TD]
[TD]29-Feb-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]28-Feb-2019[/TD]
[TD]17-Oct-2018[/TD]
[TD]17-Apr-2018[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]2-Nov-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]23-Jan-2020[/TD]
[TD]21-Mar-2020[/TD]
[TD]20-Feb-2022[/TD]
[TD]31-Jul-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]16-Jul-2021[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]5-Jan-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]6-Feb-2020[/TD]
[TD]9-Mar-2020[/TD]
[TD]7-Sep-2020[/TD]
[TD]30-Sep-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]24-Aug-2018[/TD]
[TD]25-Jun-2019[/TD]
[TD]25-Dec-2018[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]26-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]19-Jun-2020[/TD]
[TD]27-Mar-2020[/TD]
[TD]6-Apr-2020[/TD]
[TD]31-May-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]18-Oct-2018[/TD]
[TD]8-Feb-2019[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]123465[/TD]
[TD]2-Jan-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]27-May-2019[/TD]
[TD]3-Apr-2020[/TD]
[TD]5-Mar-2021[/TD]
[TD]30-Sep-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]8-May-2020[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]M123465[/TD]
[TD]4-Jan-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]10-Jan-2019[/TD]
[TD]22-Mar-2020[/TD]
[TD]27-Sep-2021[/TD]
[TD]30-Sep-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]29-Dec-2017[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]M123465[/TD]
[TD]2-Jan-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]19-Jun-2020[/TD]
[TD]1-Mar-2020[/TD]
[TD]N/A[/TD]
[TD]31-Jul-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]18-Sep-2020[/TD]
[TD]23-Oct-2018[/TD]
[TD]23-Apr-2018[/TD]
[/TR]
[TR]
[TD]M123465[/TD]
[TD]31-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]16-Jan-2020[/TD]
[TD]5-May-2020[/TD]
[TD]4-Apr-2021[/TD]
[TD]31-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]26-Jul-2018[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]M123465[/TD]
[TD]20-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]16-Jan-2020[/TD]
[TD]24-Jan-2020[/TD]
[TD]30-Mar-2020[/TD]
[TD]31-Oct-2020[/TD]
[TD]18-Jul-2119[/TD]
[TD]20-Dec-2020[/TD]
[TD]26-Jan-2018[/TD]
[TD]26-Jul-2017[/TD]
[/TR]
[TR]
[TD]M123465[/TD]
[TD]22-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]10-Jan-2019[/TD]
[TD]17-Feb-2020[/TD]
[TD]1-Apr-2021[/TD]
[TD]31-Aug-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]22-Jun-2018[/TD]
[TD]23-Oct-2019[/TD]
[TD]23-Feb-2019[/TD]
[/TR]
[TR]
[TD]M123465[/TD]
[TD]29-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]23-Jan-2020[/TD]
[TD]25-Apr-2020[/TD]
[TD]5-Mar-2021[/TD]
[TD]30-Jun-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]8-May-2020[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
[TR]
[TD]M123465[/TD]
[TD]26-Dec-2019[/TD]
[TD]7-Jul-2119[/TD]
[TD]10-Jan-2019[/TD]
[TD]2-Feb-2020[/TD]
[TD]13-Dec-2020[/TD]
[TD]31-Mar-2020[/TD]
[TD]7-Jul-2119[/TD]
[TD]8-Jan-2020[/TD]
[TD]N/A[/TD]
[TD]N/A[/TD]
[/TR]
</tbody>[/TABLE]



These are the rows that I would like to add to the bottom of the sheet. The first two rows should repeat the same across to the last column below each date column. The date data always starts at row 13 but last row and column change week to week.

[TABLE="class: grid, width: 500, align: left"]
<tbody>[TR]
[TD]Out of date[/TD]
[TD]=COUNTIFS(B13:B18,"<="&TODAY(),A13:A18,"<>M*")+COUNTIFS(B13:B18,"N/A",A13:A18,"<>GAL*")[/TD]
[/TR]
[TR]
[TD]Out of Date + M[/TD]
[TD]=COUNTIFS(B13:B18,"<="&TODAY())+COUNTIFS(B13:B18,"N/A")[/TD]
[/TR]
[TR]
[TD]total [/TD]
[TD]=COUNTIFS(A13:A18,"*",A13:A18,"<>M*")[/TD]
[/TR]
[TR]
[TD]total +M[/TD]
[TD]=COUNTIFS(A13:A18,"*"
[/TD]
[/TR]
</tbody>[/TABLE]












Any help would be greatly appreciated.
 
Last edited by a moderator:

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
My OP has an Error this should be changed

[TABLE="class: cms_table_cms_table_grid, width: 500, align: left"]
<tbody>[TR]
[TD]Out of date[/TD]
[TD]=COUNTIFS(B13:B18,"<="&TODAY(),A13:A18,"<>M*")+COUNTIFS(B13:B18,"N/A",A13:A18,"<>GAL*")[/TD]
[/TR]
</tbody>[/TABLE]




to
[TABLE="class: cms_table_cms_table_grid, width: 500, align: left"]
<tbody>[TR]
[TD]Out of date[/TD]
[TD]=COUNTIFS(B13:B18,"<="&TODAY(),A13:A18,"<>M*")+COUNTIFS(B13:B18,"N/A",A13:A18,"<>M*")[/TD]
[/TR]
</tbody>[/TABLE]
 
Upvote 0
For the first two, how about
Code:
Sub swingline()
    Dim UsdCols As Long
    UsdCols = Cells.Find("*", , xlValues, , xlByColumns, xlPrevious, , , False).Column
    With Range("A" & Rows.Count).End(xlUp)
        .Offset(1, 1).Resize(, UsdCols - 1).FormulaR1C1 = "=COUNTIFS(R13C:R[-1]C,""<=""&TODAY(),R13C1:R[-1]C1,""<>M*"")+COUNTIFS(R13C:R[-1]C,""N/A"",R13C1:R[-1]C1,""<>M*"")"
        .Offset(2, 1).Resize(, UsdCols - 1).FormulaR1C1 = "=COUNTIFS(R13C:R[-2]C,""<=""&TODAY())+COUNTIFS(R13C:R[-2]C,""N/A"")"
    End With
End Sub
 
Upvote 0
Can you manage the other two formulae, or do you need help with them?
 
Upvote 0
Glad to hear that & thanks for the feedback
 
Upvote 0

Forum statistics

Threads
1,224,817
Messages
6,181,149
Members
453,021
Latest member
Justyna P

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