VBA Clearcontents Databody Range except headers and formulas

Melimob

Active Member
Joined
Oct 16, 2011
Messages
396
Office Version
  1. 365
Hi

I have this piece of code which won't work but I basically want to reference the table and clear databody range except formulas?

Code:
With Sheets("CC Reconfiguration Data")
       .Range("B3").ListObject.DataBodyRange.SpecialCells _
         (xlCellTypeConstants, 23).ClearContents
    End With

any advice appreciated

Many thanks
 

Excel Facts

Using Function Arguments with nested formulas
If writing INDEX in Func. Arguments, type MATCH(. Use the mouse to click inside MATCH in the formula bar. Dialog switches to MATCH.
Try this:
Code:
With Sheets("CC Reconfiguration Data")
 .Range("B3").ListObject.DataBodyRange.SpecialCells([B]xlCellTypeConstants[/B]).ClearContents
End With
 
Last edited:
Upvote 0
Try this:
Code:
With Sheets("CC Reconfiguration Data")
 .Range("B3").ListObject.DataBodyRange.SpecialCells([B]xlCellTypeConstants[/B]).ClearContents
End With

Hi Yongle

Thanks for this.

I have formulas in column B but just ran it and got an error:

'No cells were found'?

When I ran this , I didn't have any data in the rest of the table to clear at this time as this is just a precaution in case there is data.

I then went in and added dummy data and it worked so I need to add an if error go to 0?

is that correct? WOuld you be kind enough to tell me where to place it in my code?

thank you

Many thanks
 
Last edited:
Upvote 0
Yes - SpecialCells returns an error if nothing is found. This is how to handle that.

Code:
With Sheets("CC Reconfiguration Data")
 On Error Resume Next    [I][COLOR=#006400] 'keeps the code running[/COLOR][/I]
 .Range("B3").ListObject.DataBodyRange.SpecialCells(xlCellTypeConstants).ClearContents
 On Error GoTo 0      [I][COLOR=#006400]'resets Error handling so that VBA does not ignore later errors[/COLOR][/I]
End With

Your code can be placed in a STANDARD module

OR can be plaed in the sheet module for Sheet "CC Reconfiguration Data"
If placed in the sheet module, there is no requirement to refer to the sheet. So the code can be simplified to...
Code:
 On Error Resume Next
 Range("B3").ListObject.DataBodyRange.SpecialCells(xlCellTypeConstants).ClearContents
 On Error GoTo 0
End With
 
Last edited:
Upvote 0
Yes - SpecialCells returns an error if nothing is found. This is how to handle that.

Code:
With Sheets("CC Reconfiguration Data")
 On Error Resume Next    [I][COLOR=#006400] 'keeps the code running[/COLOR][/I]
 .Range("B3").ListObject.DataBodyRange.SpecialCells(xlCellTypeConstants).ClearContents
 On Error GoTo 0      [I][COLOR=#006400]'resets Error handling so that VBA does not ignore later errors[/COLOR][/I]
End With

Your code can be placed in a STANDARD module

OR can be plaed in the sheet module for Sheet "CC Reconfiguration Data"
If placed in the sheet module, there is no requirement to refer to the sheet. So the code can be simplified to...
Code:
 On Error Resume Next
 Range("B3").ListObject.DataBodyRange.SpecialCells(xlCellTypeConstants).ClearContents
 On Error GoTo 0
End With

Perfect thank you so much Yongle!
 
Upvote 0

Forum statistics

Threads
1,223,901
Messages
6,175,277
Members
452,629
Latest member
SahilPolekar

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