VBA copy worksheet with option to rename

halesowenmum

Active Member
Joined
Oct 20, 2010
Messages
380
Office Version
365
Platform
Windows
Hi.

I'd like to have a button on Sheet 1 where the user clicks it and it creates an exact copy of Sheet 1* but up pops a little box that says "Please enter your name below then click Ok" and when they do that, it creates a new worksheet that is an exact replica of what's on Sheet 1 (even down to the button that the user clicked in the first place).

It doesn't really matter where within the other worksheets this newly created one is put in - what's important is that the worksheet is exactly the same as the one on Sheet 1 and they name it by their name.

The only potential problems I see with this is 1. names that are really long, too long to sit on a worksheet tab title and 2. people with the same names - any ideas within the context/restrictions of an Excel worksheet that would change how I've described wanting this would also be very useful as for the users, I think having a worksheet with their name will give them ownership of their worksheet and be really easy for them to go in and add their data in so I'd like to try and stick with using names.

* = Sheet 1 is going to be named Create My Data Entry Template btw.

Can you kindly also advise when I'm adding in the VBA, do I put it in a 'General', 'Declarations' window??

I will need help with how to go about creating the macro button as well :) to make sure that I get that bit right.

Thank you.
 

Some videos you may like

Excel Facts

Move date out one month or year
Use =EDATE(A2,1) for one month later. Use EDATE(A2,12) for one year later.

halesowenmum

Active Member
Joined
Oct 20, 2010
Messages
380
Office Version
365
Platform
Windows
Apologies, missed the editing window.

Is there a formula or something that could be added to the above VBA, that when they pick the name and the new worksheet is created with that name, it also inserts the worksheet name (ie their name) in cell A1???
 

Fluff

MrExcel MVP, Moderator
Joined
Jun 12, 2014
Messages
35,589
Office Version
365
Platform
Windows
How about
Code:
Sub halesowenmum()
    Dim ShtName As String
    Dim Flg As Boolean
    
    Do Until Flg
        ShtName = InputBox("Please enter your name")
        If ShtName = "" Then Exit Sub
        If Len(ShtName) > 31 Then
            MsgBox ("The name is too long")
        ElseIf Evaluate("isref('" & ShtName & "'!A1)") Then
            MsgBox ("That name is taken")
        Else
            Flg = True
        End If
    Loop
    Sheets("Lists").Copy , ActiveSheet
    With ActiveSheet
        .Name = ShtName
        .Range("A1").Value = ShtName
    End With
End Sub
To create the button goto the Developer tab > Insert > Select button icon (top left) under Form Controls > Click on the sheet where you want the button, when the Assign Macro window pops up select the macro name & click ok.
 

Forum statistics

Threads
1,089,381
Messages
5,407,923
Members
403,171
Latest member
mayesmail12

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