VBA copy worksheet with option to rename

halesowenmum

Active Member
Joined
Oct 20, 2010
Messages
383
Office Version
  1. 365
Platform
  1. 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.
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
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???
 
Upvote 0
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.
 
Upvote 0

Forum statistics

Threads
1,223,885
Messages
6,175,183
Members
452,615
Latest member
bogeys2birdies

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