Restrict Copy Paste only certain cells in a worksheet

gorkikumar

New Member
Joined
Aug 14, 2012
Messages
12
Hi,

Need help:

How to restrict copy paste for certain cells in excel?

For Example : Range ("A1:A20) and Range ("C5:C20")

Thanks,
Gorki
 

Some videos you may like

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.

gorkikumar

New Member
Joined
Aug 14, 2012
Messages
12
Hi,

This restricts entire workbook, i want only certain cells to be restricted.

Thanks,
Gorki
 

gorkikumar

New Member
Joined
Aug 14, 2012
Messages
12
Hi,

User can data entry on the cell but restrict paste.

Thanks,
Gorki
 

gorkikumar

New Member
Joined
Aug 14, 2012
Messages
12
Thanks for the info, but not solved the purpose.

Looking for restricting only certain cells not entire workbook.
 

rjwebgraphix

Well-known Member
Joined
May 25, 2010
Messages
588
I will play with it tonight when I have some free time at work. It doesn't look like its a quick and simple task. Might take a bit to figure out
 

rjwebgraphix

Well-known Member
Joined
May 25, 2010
Messages
588
Ok, Here's the best I can do for you....

This is the exact code I posted earlier from... Solved: Disable Cut, Copy, Paste Macro for One Column - VBA Express Forum ..and the best that I could find that does the job, with just one minor modification....

Lets start with the code and then explain...

Put the following code in ThisWorkbook
Code:
Option Explicit
 
Private Sub Workbook_Activate()
     'Force the current selection to be selected, triggering the appropriate
     'state of the cut, copy & paste commands
    Selection.Select
End Sub
 
Private Sub Workbook_BeforeClose(Cancel As Boolean)
     'Re-enable the cut, copy & paste commands
    Call ToggleCutCopyAndPaste(True)
End Sub
 
Private Sub Workbook_Deactivate()
     'Re-enable the cut, copy & paste commands
    Call ToggleCutCopyAndPaste(True)
End Sub
 
Private Sub Workbook_Open()
     'Force the current selection to be selected, triggering the appropriate
     'state of the cut, copy & paste commands
    Selection.Select
End Sub
 
Private Sub Workbook_SheetSelectionChange(ByVal Sh As Object, ByVal Target As Range)
     'Toggle the cut, copy & paste commands on selected ranges
    
    Select Case Sh.Name
    Case Is = "Sheet1"
         'Disable cut, copy & paste for Sheet1, Column A
        If Not Intersect(Target, Target.Parent.Range("A1:A20")) Is Nothing Then
            Call ToggleCutCopyAndPaste(False)
        Else
            Call ToggleCutCopyAndPaste(True)
        End If
         
    Case Is = "Sheet2"
         'Disable cut, copy & paste for Sheet2, Range A1:A20
        If Not Intersect(Target, Target.Parent.Range("G1:G20")) Is Nothing Then
            Call ToggleCutCopyAndPaste(False)
        Else
            Call ToggleCutCopyAndPaste(True)
        End If
         
    Case Else
         'Re-enable cut copy and paste commands as this is not a restricted sheet
        Call ToggleCutCopyAndPaste(True)
    End Select
End Sub
Put the following code in a standard module:
Code:
Option Explicit
 
Sub ToggleCutCopyAndPaste(Allow As Boolean)
     'Activate/deactivate cut, copy, paste and pastespecial menu items
    Call EnableMenuItem(21, Allow) ' cut
    Call EnableMenuItem(19, Allow) ' copy
    Call EnableMenuItem(22, Allow) ' paste
    Call EnableMenuItem(755, Allow) ' pastespecial
     
     'Activate/deactivate drag and drop ability
'    Application.CellDragAndDrop = Allow
     
     'Activate/deactivate cut, copy, paste and pastespecial shortcut keys
    With Application
        Select Case Allow
        Case Is = False
            .OnKey "^c", "CutCopyPasteDisabled"
            .OnKey "^v", "CutCopyPasteDisabled"
            .OnKey "^x", "CutCopyPasteDisabled"
            .OnKey "+{DEL}", "CutCopyPasteDisabled"
            .OnKey "^{INSERT}", "CutCopyPasteDisabled"
        Case Is = True
            .OnKey "^c"
            .OnKey "^v"
            .OnKey "^x"
            .OnKey "+{DEL}"
            .OnKey "^{INSERT}"
        End Select
    End With
End Sub
 
Sub EnableMenuItem(ctlId As Integer, Enabled As Boolean)
     'Activate/Deactivate specific menu item
    Dim cBar As CommandBar
    Dim cBarCtrl As CommandBarControl
    For Each cBar In Application.CommandBars
        If cBar.Name <> "Clipboard" Then
            Set cBarCtrl = cBar.FindControl(ID:=ctlId, recursive:=True)
            If Not cBarCtrl Is Nothing Then cBarCtrl.Enabled = Enabled
        End If
    Next
End Sub
 
Sub CutCopyPasteDisabled()
     'Inform user that the functions have been disabled
    MsgBox "Sorry! Cutting, copying and pasting have been disabled in this workbook!"
End Sub
My minor modification I left in, but commented it out. I removed the following line from the main toggle function...

Application.CellDragAndDrop = Allow

Unfortunately, when this line is ran, when you are not in the range that is ok to copy and paste from it deselects whatever you copied and then unable to paste.

The up side is that this will disable cut, copy and paste for the range you want. The example shows Range("A1:A20") of Sheet1 and Range("G1:G20") of Sheet2, but you can modify these as needed. That is part of what you copy to ThisWorkbook.

The down side is that people could still drag and drop, which may or may not be an issue for you.

Another down side of this code I found while playing with it is that it is only ran when the selection changes, so if you are already within the range you shouldn't be able to paste to, then go to another worksheet and in that change to cells that you can copy and paste from and to, then switch back to the other sheet. Since the selection is not changing, it will allow you to paste into it. This could be fixed by adding some additional code when switching worksheets to detect the range the current selection is in and disable or enable accordingly.

There is also a visa versa to that. If you're in one sheet with a restricted cell selected and switch to another sheet where the cell is not restricted, you won't be able to copy/paste till you change cells and come back again.... Again, this could be fixed with a modification to the code for switching worksheets.

Get this code working as is in your workbook, then if you have any other questions, concerns or modifications needed, lets discuss what you'll need to do to change it to get it to behave how you want. I'm not sure if the drag and drop issue will be a problem or not, but as is, it makes the rest of it not work right.... An option could be to disable drag and drop in its entirety, with only limiting cut,copy,paste to certain cells.

I'll shut up now, you got some work to do. :)
 

Forum statistics

Threads
1,089,475
Messages
5,408,462
Members
403,208
Latest member
JFoley182

This Week's Hot Topics

  • help please
    SORRY NOT ANY GOOD AT EXCEL SO HELP WOULD BE MUCH APPRECIATED this formula is in a sheet called ignore...
  • two formulas needed
    Hello, I'll try my best to explain this: First formula needed in Sheet1 cell A2: If Sheet1 cell B2 = Sheet2 cell B2 then return a 1. If not then...
  • Dynamic Counts
    Good afternoon, we are tidying up some data & the data seems to be growing quicker than we are tidying it up! What we confirm (by reviewing it...
  • Help Excel formula eliminate duplicate values and keep only 2 identical rows.
    as picture below column A has a duplicate value. but the values are not the same as the rule. sometimes 4 rows, sometimes 10 rows or 7 or 9...
  • Macro Compile Error Sub or Function not defined
    Hello, I am trying to run macros from a validation list, all macros have been created and run perfectly on there own but I'm getting a compile...
  • Last row combined with Current Region VBA
    I'm generally happy finding the last row of data through something like Lastrow = Cells(Rows.Count, "D").End(xlUp) but I don't always receive data...
Top