Changing recorded macro when trying to format a sheet - Need dynamic selection of cells

nidhinair22

New Member
Joined
Jan 16, 2023
Messages
3
Office Version
  1. 2016
Platform
  1. Windows
Hi..I am new to VBA. I can able to make simple macros work by just recording them. Basically, I am pulling data report from ERP and formatting and filtering out irrelevant data so that I can take that data and make some pivot. My issue is that the rows of data will vary while the columns will stay the same. I need to turn these into dynamic ranges so it will select everything. I will list the macros in the order of which they are ran.

As I am new to this, please help me to get correct code/.

Thank you in advance!

VBA Code:
Sub BMT()
'
' BMT Macro
'
' Keyboard Shortcut: Ctrl+y
'
    ActiveSheet.Range("$A$1:$U$11096").AutoFilter Field:=1, Criteria1:=Array( _
        "AC", "AE", "AI", "AK", "AM", "AW", "GBS", "KM", "NS", "PA", "PAL", "PTE", "RJI", "TQ", "WW") _
        , Operator:=xlFilterValues
    ActiveWindow.SmallScroll Down:=-33
    Rows("2:2").Select
    ActiveWindow.SmallScroll Down:=-24
    Range(Selection, Selection.End(xlDown)).Select
    Selection.Delete Shift:=xlUp
    Range("A9000").Select
    ActiveSheet.Range("$A$1:$U$8999").AutoFilter Field:=1
    Range("A2").Select
    ActiveSheet.Range("$A$1:$U$8999").AutoFilter Field:=2, Criteria1:=Array( _
        "ED", "HO", "PP", "TD"), Operator:=xlFilterValues
    ActiveWindow.SmallScroll Down:=-24
    Rows("2:2").Select
    ActiveWindow.SmallScroll Down:=-33
    Range(Selection, Selection.End(xlDown)).Select
    Selection.Delete Shift:=xlUp
    Range("A4322").Select
    ActiveSheet.Range("$A$1:$U$4321").AutoFilter Field:=2
    Range("A2").Select
    ActiveSheet.Range("$A$1:$U$4321").AutoFilter Field:=3, Criteria1:=Array( _
        "CR", "CV", "EL", "EP", "GN", "IE", "VG", "WS", "WT"), Operator:=xlFilterValues
    ActiveWindow.SmallScroll Down:=-30
    Rows("2:2").Select
    ActiveWindow.SmallScroll Down:=-39
    Range(Selection, Selection.End(xlDown)).Select
    Selection.Delete Shift:=xlUp
    Range("A2206").Select
    ActiveSheet.Range("$A$1:$U$2205").AutoFilter Field:=3
    Range("A2").Select
    ActiveWorkbook.Save
    Columns("O:O").Select
    Selection.Insert Shift:=xlToRight
    Range("O1").Select
    ActiveCell.FormulaR1C1 = "DR/CR"
    Range("O2").Select
    Columns("O:O").EntireColumn.AutoFit
    Range("O2").Select
    ActiveWindow.SmallScroll Down:=-12
    ActiveSheet.Range("$A$1:$V$2205").AutoFilter Field:=14, Criteria1:="<0", _
        Operator:=xlAnd
    ActiveWindow.SmallScroll Down:=-21
    ActiveCell.FormulaR1C1 = "CR"
    Range("O2").Select
    ActiveWindow.SmallScroll Down:=-18
    Selection.Copy
    Range("O43:O2204").Select
    ActiveSheet.Paste
    Application.CutCopyMode = False
    Range("A2").Select
    ActiveSheet.Range("$A$1:$V$2205").AutoFilter Field:=14
    ActiveSheet.Range("$A$1:$V$2205").AutoFilter Field:=14, Criteria1:=">=0", _
        Operator:=xlAnd, Criteria2:="<=5"
    ActiveWindow.SmallScroll Down:=-21
    Range("O55").Select
    ActiveWindow.SmallScroll Down:=-12
    ActiveCell.FormulaR1C1 = "SM BAL"
    Range("O55").Select
    Selection.Copy
    Range("O163:O2202").Select
    ActiveSheet.Paste
    Application.CutCopyMode = False
    Range("A55").Select
    ActiveSheet.Range("$A$1:$V$2205").AutoFilter Field:=14
    ActiveSheet.Range("$A$1:$V$2205").AutoFilter Field:=14, Criteria1:=">=-5", _
        Operator:=xlAnd, Criteria2:="<=0"
    ActiveWindow.SmallScroll Down:=-21
    Range("O69").Select
    ActiveWindow.SmallScroll Down:=-21
    ActiveCell.FormulaR1C1 = "SM BAL"
    Range("O69").Select
    Selection.Copy
    Range("O81").Select
    Range(Selection, Selection.End(xlDown)).Select
    ActiveSheet.Paste
    Application.CutCopyMode = False
    Range("A69").Select
    ActiveSheet.Range("$A$1:$V$2205").AutoFilter Field:=14
    Columns("O:O").Select
    With Selection
        .HorizontalAlignment = xlCenter
        .VerticalAlignment = xlBottom
        .WrapText = False
        .Orientation = 0
        .AddIndent = False
        .IndentLevel = 0
        .ShrinkToFit = False
        .ReadingOrder = xlContext
        .MergeCells = False
    End With
    With Selection
        .HorizontalAlignment = xlGeneral
        .VerticalAlignment = xlBottom
        .WrapText = False
        .Orientation = 0
        .AddIndent = False
        .IndentLevel = 0
        .ShrinkToFit = False
        .ReadingOrder = xlContext
        .MergeCells = False
    End With
    With Selection
        .HorizontalAlignment = xlCenter
        .VerticalAlignment = xlBottom
        .WrapText = False
        .Orientation = 0
        .AddIndent = False
        .IndentLevel = 0
        .ShrinkToFit = False
        .ReadingOrder = xlContext
        .MergeCells = False
    End With
    Range("N2").Select
    Columns("O:O").ColumnWidth = 6.43
    Range("A2").Select
    ActiveWindow.SmallScroll Down:=-12
    ActiveSheet.Range("$A$1:$V$2205").AutoFilter Field:=4, Criteria1:=Array( _
        "C7I100", "C7I111", "C7I222", "C7I444"), Operator:=xlFilterValues
    ActiveWindow.SmallScroll Down:=-30
    Rows("1326:1326").Select
    ActiveWindow.SmallScroll Down:=-36
    Range(Selection, Selection.End(xlDown)).Select
    Selection.Delete Shift:=xlUp
    Range("A2153").Select
    ActiveSheet.Range("$A$1:$V$2152").AutoFilter Field:=4
    Range("A2").Select
    ActiveWorkbook.Save
    ActiveSheet.Range("$A$1:$V$2152").AutoFilter Field:=4, Criteria1:="C1M008"
    ActiveSheet.Range("$A$1:$V$2152").AutoFilter Field:=4
    Range("A2").Select
    ActiveSheet.Range("$A$1:$V$2152").AutoFilter Field:=4, Criteria1:="C1V500"
    ActiveWindow.SmallScroll Down:=-21
    Rows("1195:1211").Select
    Selection.Delete Shift:=xlUp
    Range("A2136").Select
    ActiveSheet.Range("$A$1:$V$2135").AutoFilter Field:=4
    ActiveSheet.Range("$A$1:$V$2135").AutoFilter Field:=4, Criteria1:="C1S081"
    ActiveWindow.SmallScroll Down:=-27
    Rows("913:913").Select
    ActiveWindow.SmallScroll Down:=-27
    Range(Selection, Selection.End(xlDown)).Select
    Selection.Delete Shift:=xlUp
    Range("A2114").Select
    ActiveSheet.Range("$A$1:$V$2113").AutoFilter Field:=4
    Range("E6").Select
    ActiveSheet.Range("$A$1:$V$2113").AutoFilter Field:=5, Criteria1:= _
        "MATERIAL for EPOXY COATING"
    ActiveSheet.Range("$A$1:$V$2113").AutoFilter Field:=5
    ActiveSheet.Range("$A$1:$V$2113").AutoFilter Field:=4, Criteria1:="C5M002"
    ActiveWindow.SmallScroll Down:=-18
    Rows("1245:1248").Select
    ActiveWindow.SmallScroll Down:=-24
    Selection.Delete Shift:=xlUp
    Range("A2110").Select
    ActiveSheet.Range("$A$1:$V$2109").AutoFilter Field:=4
    Range("A2").Select
    ActiveWorkbook.Save
    Columns("D:D").Select
    Selection.Insert Shift:=xlToRight
    Range("D1").Select
    ActiveCell.FormulaR1C1 = "DEPART"
    Range("D2").Select
    ActiveWindow.SmallScroll Down:=-18
    Columns("D:D").ColumnWidth = 5.29
    ActiveWindow.SmallScroll Down:=-9
    ActiveSheet.Range("$A$1:$W$2109").AutoFilter Field:=3, Criteria1:=Array( _
        "BK", "CO", "CT", "RB", "TR"), Operator:=xlFilterValues
    ActiveWindow.SmallScroll Down:=-42
    ActiveCell.FormulaR1C1 = "CORP"
    Range("D2").Select
    Selection.Copy
    Range("D3:D2109").Select
    ActiveSheet.Paste
    Application.CutCopyMode = False
    Range("A2").Select
    ActiveSheet.Range("$A$1:$W$2109").AutoFilter Field:=3
    Range("A2").Select
    ActiveSheet.Range("$A$1:$W$2109").AutoFilter Field:=4, Criteria1:="="
    ActiveWindow.SmallScroll Down:=-24
    Range("D146").Select
    ActiveWindow.SmallScroll Down:=-24
    ActiveCell.FormulaR1C1 = "=RC[-1]"
    Range("D146").Select
    Selection.Copy
    Range("D147:D2081").Select
    ActiveSheet.Paste
    Application.CutCopyMode = False
    Range("A146").Select
    ActiveSheet.Range("$A$1:$W$2109").AutoFilter Field:=4
    Range("A2").Select
    ActiveWorkbook.Save
    ActiveWindow.SmallScroll Down:=-90
    ActiveWorkbook.Save
    ActiveWindow.SmallScroll Down:=-27
    ActiveWorkbook.Save
    ActiveWindow.SmallScroll Down:=-87
    Columns("K:K").Select
    Selection.Insert Shift:=xlToRight
    Range("K1").Select
    ActiveCell.FormulaR1C1 = "Mnth/Yr"
    Range("K2").Select
    ActiveWindow.SmallScroll Down:=-12
    ActiveSheet.Range("$A$1:$X$2109").AutoFilter Field:=10, Operator:= _
        xlFilterValues, Criteria2:=Array(0, "12/30/2021", 0, "11/19/2020", 0, "11/12/2019" _
        , 0, "12/30/2018", 0, "6/11/2016", 0, "10/24/2015", 0, "12/29/2014", 0, "1/31/2013", 0, _
        "3/21/2011", 0, "10/30/2007")
    ActiveWindow.SmallScroll Down:=-21
    Range("K2").Select
    ActiveWindow.SmallScroll Down:=-9
    ActiveCell.FormulaR1C1 = "UPTO 2021"
    Range("K2").Select
    Selection.Copy
    Range("K145:K2108").Select
    ActiveSheet.Paste
    Application.CutCopyMode = False
    Range("A2").Select
    ActiveSheet.Range("$A$1:$X$2109").AutoFilter Field:=10
    ActiveSheet.Range("$A$1:$X$2109").AutoFilter Field:=10, Operator:= _
        xlFilterValues, Criteria2:=Array(0, "12/31/2022")
    ActiveWindow.SmallScroll Down:=-21
    Range("K3").Select
    ActiveWindow.SmallScroll Down:=-18
    ActiveCell.FormulaR1C1 = "=TEXT(RC[-1],MMM)"
    Range("K3").Select
    Selection.ClearContents
    Columns("K:K").Select
    Selection.Delete Shift:=xlToLeft
    Range("A3").Select
    ActiveSheet.Range("$A$1:$W$2109").AutoFilter Field:=10
    Range("A2").Select
    ActiveWorkbook.Save
    ActiveWindow.SmallScroll Down:=-12
End Sub
 
Last edited by a moderator:

Excel Facts

Difference between two dates
Secret function! Use =DATEDIF(A2,B2,"Y")&" years"&=DATEDIF(A2,B2,"YM")&" months"&=DATEDIF(A2,B2,"MD")&" days"
I have tried to make some changes to the code but there is no data available for me to test it.
Usually, when you have a code generated with the recorder tool, you can remove some rows with no changes, for example:
- ActiveWindow.SmallScroll (This just records the scroll, you don't need it for the macro)
- Remove some random ranges selections. (For example, "Range ("O2").Select" and them "Selection.Copy", you can reduce that for "Range("O2").Copy"
Here is the code:
VBA Code:
Sub BMT()
    Dim lastRow As Long
    lastRow = ActiveSheet.Cells(Rows.Count, 1).End(xlUp).Row

    With ActiveSheet
        .Range("$A$1:$U$" & lastRow).AutoFilter Field:=1, Criteria1:=Array("AC", "AE", "AI", "AK", "AM", "AW", "GBS", "KM", "NS", "PA", "PAL", "PTE", "RJI", "TQ", "WW"), Operator:=xlFilterValues
        .Range("A2:A" & lastRow).EntireRow.Delete
        .Range("$A$1:$U$" & lastRow).AutoFilter Field:=2, Criteria1:=Array("ED", "HO", "PP", "TD"), Operator:=xlFilterValues
        .Range("A2:A" & lastRow).EntireRow.Delete
        .Range("$A$1:$U$" & lastRow).AutoFilter Field:=3, Criteria1:=Array("CR", "CV", "EL", "EP", "GN", "IE", "VG", "WS", "WT"), Operator:=xlFilterValues
        .Range("A2:A" & lastRow).EntireRow.Delete
        .Columns("O:O").Insert
        .Range("O1").Value = "DR/CR"
        .Columns("O:O").EntireColumn.AutoFit
        .Range("$A$1:$V$" & lastRow).AutoFilter Field:=14, Criteria1:="<0", Operator:=xlAnd
        .Range("O2:O" & lastRow).Value = "CR"
        .Range("$A$1:$V$" & lastRow).AutoFilter Field:=14, Criteria1:=">=0", Criteria2:="<=5"
        .Range("O55").Value = "SM BAL"
        .Range("O55:O" & lastRow).Value = "SM BAL"
        .Range("O69").Copy Destination:=.Range("O81:O" & lastRow)
        .Range("A1:V" & lastRow).AutoFilter
    End With
    ActiveWorkbook.Save
End Sub

Please, let me know if there are some missing steps that are required. :)
 
Upvote 0
I have tried to make some changes to the code but there is no data available for me to test it.
Usually, when you have a code generated with the recorder tool, you can remove some rows with no changes, for example:
- ActiveWindow.SmallScroll (This just records the scroll, you don't need it for the macro)
- Remove some random ranges selections. (For example, "Range ("O2").Select" and them "Selection.Copy", you can reduce that for "Range("O2").Copy"
Here is the code:
VBA Code:
Sub BMT()
    Dim lastRow As Long
    lastRow = ActiveSheet.Cells(Rows.Count, 1).End(xlUp).Row

    With ActiveSheet
        .Range("$A$1:$U$" & lastRow).AutoFilter Field:=1, Criteria1:=Array("AC", "AE", "AI", "AK", "AM", "AW", "GBS", "KM", "NS", "PA", "PAL", "PTE", "RJI", "TQ", "WW"), Operator:=xlFilterValues
        .Range("A2:A" & lastRow).EntireRow.Delete
        .Range("$A$1:$U$" & lastRow).AutoFilter Field:=2, Criteria1:=Array("ED", "HO", "PP", "TD"), Operator:=xlFilterValues
        .Range("A2:A" & lastRow).EntireRow.Delete
        .Range("$A$1:$U$" & lastRow).AutoFilter Field:=3, Criteria1:=Array("CR", "CV", "EL", "EP", "GN", "IE", "VG", "WS", "WT"), Operator:=xlFilterValues
        .Range("A2:A" & lastRow).EntireRow.Delete
        .Columns("O:O").Insert
        .Range("O1").Value = "DR/CR"
        .Columns("O:O").EntireColumn.AutoFit
        .Range("$A$1:$V$" & lastRow).AutoFilter Field:=14, Criteria1:="<0", Operator:=xlAnd
        .Range("O2:O" & lastRow).Value = "CR"
        .Range("$A$1:$V$" & lastRow).AutoFilter Field:=14, Criteria1:=">=0", Criteria2:="<=5"
        .Range("O55").Value = "SM BAL"
        .Range("O55:O" & lastRow).Value = "SM BAL"
        .Range("O69").Copy Destination:=.Range("O81:O" & lastRow)
        .Range("A1:V" & lastRow).AutoFilter
    End With
    ActiveWorkbook.Save
End Sub

Please, let me know if there are some missing steps that are required. :)
Dear bferraz,
i was facing error while running this code. I can able to send to u the data. Can u pls help me out.
 
Upvote 0

Forum statistics

Threads
1,223,164
Messages
6,170,444
Members
452,326
Latest member
johnshaji

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