Insert & Delete Table Rows With Worksheet Protection

What This VBA Code Does
When you check the “Insert Rows” option in the Protect Sheets dialog box, it only allows for inserting entire rows within the spreadsheet. If you go to insert a Table row, the option is grayed out. Why? I have no idea!
So what’s the solution? Well, we can use VBA to unprotect the worksheet and insert or delete table rows based on the current selection. I typically will assign these macros to square buttons that have a plus & minus sign to allow the users to easily modify the table. Here is an example of a typical table setup I would create:

Below is the VBA code I use in my own projects & products to accomplish maintaining the integrity of my spreadsheets while allowing users to modify data tables in the spreadsheets.
Function To Determine If Cell Selection Is Within A Table
This is a function that will be used by both the AddTableRows and DeleteTableRows VBA macros. What it does is simply determine if a cell is within an Excel Table or not, returning a True or False value. You will need to paste this code into your VBA module along with the other macros below this section.
Function IsCellInTable(cell As Range) As Boolean
'PURPOSE: Determine if a cell is within an Excel Table
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
IsCellInTable = False
On Error Resume Next
IsCellInTable = (cell.ListObject.Name <> "")
On Error GoTo 0
End Function
Inserting Table Rows
Sub AddTableRows()
'PURPOSE: Add table row based on user's selection
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
Dim rng As Range
Dim InsertRows As Long
Dim StartRow As Long
Dim InsideTable As Boolean
Dim RowToBottom As Boolean
Dim ReProtect As Boolean
Dim Password As String
Dim area As Range
'Optimize Code
Application.ScreenUpdating = False
'What is the worksheet password?
Password = ""
'Set Range Variable
On Error GoTo InvalidSelection
Set rng = Selection
On Error GoTo 0
'Unprotect Worksheet
With ActiveSheet
If .ProtectContents Or .ProtectDrawingObjects Or .ProtectScenarios Then
On Error GoTo InvalidPassword
.Unprotect Password
ReProtect = True
On Error GoTo 0
End If
End With
'Loop Through each Area in Selection
For Each area In rng.Areas
'Is selected Cell within a table?
InsideTable = IsCellInTable(area.Cells(1, 1))
'Is selected cell 1 row under a table?
RowToBottom = IsCellInTable(area.Cells(1, 1).Offset(-1))
'How Many Rows In Selection?
InsertRows = area.Rows.Count
'Selection Not Within Table?
If Not InsideTable And Not RowToBottom Then GoTo InvalidSelection
'Add Rows To Table
If InsideTable Then
'Which Row in Table is selected?
With area.Cells(1, 1)
x = .Row
y = .ListObject.DataBodyRange.Row
Z = .ListObject.DataBodyRange.Rows.Count
End With
StartRow = Z - ((y + Z - 1) - x)
'Insert rows based on how many rows are currently selected
For x = 1 To InsertRows
area.ListObject.ListRows.Add (StartRow)
Next x
ElseIf RowToBottom Then
For x = 1 To InsertRows
area.Cells(1, 1).Offset(-1).ListObject.ListRows.Add AlwaysInsert:=True
Next x
End If
Next area
'Protect Worksheet
If ReProtect = True Then ActiveSheet.Protect Password
Exit Sub
'ERROR HANDLERS
InvalidSelection:
MsgBox "You must select a cell within or directly below an Excel table"
If ReProtect = True Then ActiveSheet.Protect Password
Exit Sub
InvalidPassword:
MsgBox "Failed to unlock password with the following password: " & Password
Exit Sub
End Sub
Deleting Table Rows
Sub DeleteTableRows()
'PURPOSE: Delete table row based on user's selection
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault
Dim rng As Range
Dim DeleteRng As Range
Dim cell As Range
Dim TempRng As Range
Dim Answer As Variant
Dim Password As String
Dim area As Range
Dim ReProtect As Boolean
'What is the worksheet password?
Password = ""
'Set Range Variable
On Error GoTo InvalidSelection
Set rng = Selection
On Error GoTo 0
'Unprotect Worksheet
With ActiveSheet
If .ProtectContents Or ProtectDrawingObjects Or ProtectScenarios Then
On Error GoTo InvalidPassword
.Unprotect Password
ReProtect = True
On Error GoTo 0
End If
End With
'Loop Through each Area in Selection
For Each area In rng.Areas
For Each cell In area.Cells.Columns(1)
'Is selected Cell within a table?
InsideTable = IsCellInTable(cell)
'Gather rows to delete
If InsideTable Then
On Error GoTo InvalidActiveCell
Set TempRng = Intersect(cell.EntireRow, ActiveCell.ListObject.DataBodyRange)
On Error GoTo 0
If DeleteRng Is Nothing Then
Set DeleteRng = TempRng
Else
Set DeleteRng = Union(TempRng, DeleteRng)
End If
End If
Next cell
Next area
'Error Handling
If DeleteRng Is Nothing Then GoTo InvalidSelection
If DeleteRng.Address = ActiveCell.ListObject.DataBodyRange.Address Then GoTo DeleteAllRows
If ActiveCell.ListObject.DataBodyRange.Rows.Count = 1 Then GoTo DeleteOnlyRow
'Ask User To confirm delete (since this cannot be undone)
DeleteRng.Select
If DeleteRng.Rows.Count = 1 And DeleteRng.Areas.Count = 1 Then
Answer = MsgBox("Are you sure you want to delete the currently selected table row? " & _
" This cannot be undone...", vbYesNo, "Delete Row?")
Else
Answer = MsgBox("Are you sure you want to delete the currently selected table rows? " & _
" This cannot be undone...", vbYesNo, "Delete Rows?")
End If
'Delete row (if wanted)
If Answer = vbYes Then DeleteRng.Delete xlShiftUp
'Protect Worksheet
If ReProtect = True Then ActiveSheet.Protect Password
Exit Sub
'ERROR HANDLERS
InvalidActiveCell:
MsgBox "The first cell you select must be inside an Excel Table. " & _
"The first cell you selected was cell " & ActiveCell.Address, vbCritical, "Invalid Selection!"
If ReProtect = True Then ActiveSheet.Protect Password
Exit Sub
InvalidSelection:
MsgBox "You must select a cell within an Excel table", vbCritical, "Invalid Selection!"
If ReProtect = True Then ActiveSheet.Protect Password
Exit Sub
DeleteAllRows:
MsgBox "You cannot delete all the rows in the table. " & _
"You must leave at least one row existing in a table", vbCritical, "Cannot Delete!"
If ReProtect = True Then ActiveSheet.Protect Password
Exit Sub
DeleteOnlyRow:
MsgBox "You cannot delete the only row in the table.", vbCritical, "Cannot Delete!"
If ReProtect = True Then ActiveSheet.Protect Password
Exit Sub
InvalidPassword:
MsgBox "Failed to unlock password with the following password: " & Password
Exit Sub
End Sub
Using VBA Code Found On The Internet
Now that you’ve found some VBA code that could potentially solve your Excel automation problem, what do you do with it? If you don’t necessarily want to learn how to code VBA and are just looking for the fastest way to implement this code into your spreadsheet, I wrote an article (with video) that explains how to get the VBA code you’ve found running on your spreadsheet.
Getting Started Automating Excel
Are you new to VBA and not sure where to begin? Check out my quickstart guide to learning VBA. This article won’t overwhelm you with fancy coding jargon, as it provides you with a simplistic and straightforward approach to the basic things I wish I knew when trying to teach myself how to automate tasks in Excel with VBA Macros.
Also, if you haven’t checked out Excel’s latest automation feature called Power Query, I have put together a beginner’s guide for automating with Excel’s Power Query feature as well! This little-known built-in Excel feature allows you to merge and clean data automatically with little to no coding!
How Do I Modify This To Fit My Specific Needs?
Chances are this post did not give you the exact answer you were looking for. We all have different situations and it’s impossible to account for every particular need one might have. That’s why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to get quick answers to complex problems in Excel, PowerPoint, VBA, you name it!
I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee that 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don’t have time to fit everyone’s questions in (there never seem to be quite enough hours in the day!).
I wish you the best of luck and I hope this tutorial gets you heading in the right direction!
After 10+ years of creating macros and developing add-ins, I've compiled all the hacks I wish I had known years ago!

Keep Learning
Chris Newman
Chris is a finance professional and Excel MVP recognized by Microsoft since 2016. With his expertise, he founded TheSpreadsheetGuru blog to help fellow Excel users, where he shares his vast creative solutions & expertise. In addition, he has developed over 7 widely-used Excel Add-ins that have been embraced by individuals and companies worldwide.