Clearing Content of Cells except Header Row, from a Separate "Run Macros" tab

karl_learnvba

New Member
Joined
Oct 10, 2019
Messages
12
Office Version
  1. 365
Platform
  1. Windows
Hello all, Just diving into VBA - Thank you in advance for your help.

I have a worksheet which from which I have associated macros to buttons to launch a series of VBA macros - Called "Process". I would like to run all macros from the "process" tab

I have another worksheet called "Working Dataset" where I am looking to clear the content of the cells, below the header.

The problem that I am experiencing is that the VBA code is clearing the content from the "Process" worksheet when the code is run from the button, rather than the "Working Dataset" worksheet.

Here is the code that I developed (i know it is basic!!) - what am I doing wrong ?

VBA Code:
Sub YY()

    Dim wb As Workbook: Set wb = ThisWorkbook
    Dim ws, ws1 As Worksheets: Set ws = wb.Worksheets("Working Dataset")
        
    
    'Clear the contents of the columns below the header
    
        ws.Range(Cells(2, 1), Cells(Rows.Count, 1)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 2)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 3)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 4)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 5)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 6)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 7)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 8)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 9)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 10)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 11)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 12)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 13)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 14)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 15)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 16)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 17)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 18)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 19)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 20)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 21)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 22)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 23)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 24)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 25)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 26)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 27)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 28)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 29)).ClearContents
        ws.Range(Cells(2, 1), Cells(Rows.Count, 30)).ClearContents
            
    'This routine copies the SI data into the working data tab
        
    Set ws1 = wb.Worksheets("SI Data")
        
        ws1.Range("SI_Data_Import").Copy
        ws.Range("A2").PasteSpecial xlPasteValues
        ws.Range("A:A").NumberFormat = "General"
        ws.Range("C:C").NumberFormat = "General"
        ws.Range("Q:W").NumberFormat = "#,##0"
        ws.Range("Z:AC").NumberFormat = "#,##0"
        ws.Range("AD:AD").NumberFormat = "0%"
        ws.Range("AE:AG").NumberFormat = "#,##0"
        ws.Range("AN:AN").NumberFormat = "General"
        ws.Range("AQ:AQ").NumberFormat = "General"


End Sub
 

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Try this:
VBA Code:
Sub YY()
    Dim wb As Workbook, ws As Worksheet, ws1 As Worksheet, Lr As Long
    Set wb = ThisWorkbook
    Set ws = wb.Worksheets("Working Dataset")
    Set ws1 = wb.Worksheets("SI Data")
    Lr = ws.Range("A" & Rows.Count).End(xlUp).Row
    
        ws.Range("A2:AD" & Lr).ClearContents
        ws1.Range("SI_Data_Import").Copy
        ws.Range("A2").PasteSpecial xlPasteValues
        ws.Range("A:A").NumberFormat = "General"
        ws.Range("C:C").NumberFormat = "General"
        ws.Range("Q:W").NumberFormat = "#,##0"
        ws.Range("Z:AC").NumberFormat = "#,##0"
        ws.Range("AD:AD").NumberFormat = "0%"
        ws.Range("AE:AG").NumberFormat = "#,##0"
        ws.Range("AN:AN").NumberFormat = "General"
        ws.Range("AQ:AQ").NumberFormat = "General"
End Sub
 
Upvote 0
Solution
Thank you v much @maabadi - works perfectly as I wanted it to.

Quick Question about the line that you introduced:

VBA Code:
Lr = ws.Range("A" & Rows.Count).End(xlUp).Row

Could you help me to understand how it works?

Thanks v much
 
Upvote 0
Try this:
Rich (BB code):
Sub YY()
    Dim wb As Workbook, ws As Worksheet, ws1 As Worksheet, Lr As Long
    Set wb = ThisWorkbook
    Set ws = wb.Worksheets("Working Dataset")
    Set ws1 = wb.Worksheets("SI Data")
    Lr = ws.Range("A" & Rows.Count).End(xlUp).Row
   
        ws.Range("A2:AD" & Lr).ClearContents
        ws1.Range("SI_Data_Import").Copy
        ws.Range("A2").PasteSpecial xlPasteValues
        ws.Range("A:A").NumberFormat = "General"
        ws.Range("C:C").NumberFormat = "General"
        ws.Range("Q:W").NumberFormat = "#,##0"
        ws.Range("Z:AC").NumberFormat = "#,##0"
        ws.Range("AD:AD").NumberFormat = "0%"
        ws.Range("AE:AG").NumberFormat = "#,##0"
        ws.Range("AN:AN").NumberFormat = "General"
        ws.Range("AQ:AQ").NumberFormat = "General"
End Sub
Just noting that your 8 NumberFormat code lines can be replaced by these three code lines...
VBA Code:
  ws.[A:A,C:C,AN:AN,AQ:AQ].NumberFormat = "General"
  ws.[Q:W,Z:AC,AE:AG].NumberFormat = "#,##0"
  ws.[AD:AD].NumberFormat = "0%"
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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