Using the CommandPrompt Button to Add Rows - How to exclude certain row ranges from being selected?

Kimmel

New Member
Joined
Jul 10, 2019
Messages
1
Hello MrExcel Forums!

First post, so please let me know if I am performing any forum faux pas on here. I searched/lurked through many threads but couldn't seem to find the answer I was looking for. I made an excel tool for some very not savvy excel people. It is protected and I'm building macros into buttons so they have some ability to alter the data tool in specific ways. Essentially, I'd like to give users the ability to insert rows, retaining formatting of formulas, and the ability to choose where they want to insert the row. This is my code so far:

Private Sub CommandButton1_Click()
Dim rowNum As Integer
On Error Resume Next
rowNum = Application.InputBox(Prompt:="Enter Row Number where you want to add a row:", _
Title:="Insert New Row", Type:=1)
Unprotect Password:="M"
Rows(rowNum & ":" & rowNum).Copy
Rows(rowNum & ":" & rowNum).Insert Shift:=xlDown
Protect Password:="M"
End Sub

I have a header (Rows 1-3) and a footer (currently Rows 36-40, but that range will change every time a row is added) that I need to remain protected and shouldn't be copied/touched. I've named the header and footer range as one unit (HeaderFooter, rows 1-3 &36-40) in Excel and have been trying to figure out how to exclude any row selection that sits in that range (i.e. if someone were to type in to add a row at "36", for the macro to not perform the copy/insert) or to only allow selections within another named range I created (DataSet, rows 4-35).

Would anyone be able to provide me with some guidance? Thank you so very much in advance!
 

Excel Facts

Get help while writing formula
Click the italics "fx" icon to the left of the formula bar to open the Functions Arguments dialog. Help is displayed for each argument.
Welcome to the forum :)

The INTERSECT function returns the overlap between ranges (if any)

Code:
Sub PreventRowsInserted()
    Dim rowNum As Long, Banned As Range
    Set Banned = ActiveSheet.Range("HeaderFooter")

    rowNum = Application.InputBox(Prompt:="Enter Row Number where you want to add a row:", Title:="Insert New Row", Type:=1)

    If Not Intersect(Banned, Rows(rowNum)) Is Nothing Then
        MsgBox "cannot insert rows inside header and footer area"
        Exit Sub
    Else
        MsgBox "carry on with rest of macro"
    End If
End Sub
 
Last edited:
Upvote 0

Forum statistics

Threads
1,214,666
Messages
6,120,806
Members
448,990
Latest member
rohitsomani

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