Create a button that pops up a form where I can fill information

lindsay13

New Member
Joined
Jun 27, 2019
Messages
2
Hi! I need some help here!
I have been trying to
1)Create a button that pops up a form where I can fill in "Name" and "Time".
2)I have a word template, after fill in "Name" and "Date" in the form, I wish to link those two pieces of information to the title of the word template. For example, I filled in "Joe Ham" and "2019-01-08" in the Excel form and click ok, then I go to a file location "D:\An example" and can see the word template named "Joe Ham_2019-01-08"

I am very new to macro and I really appreciate any help!!!
 

Excel Facts

Fastest way to copy a worksheet?
Hold down the Ctrl key while dragging tab for Sheet1 to the right. Excel will make a copy of the worksheet.
I have created a demo which does what you ask.

A Userform must be created. In the properties of the userform in (name), change the default to 'GetFileName', to make the name meaningful


The three textboxes and the two buttons in the form also have different names from the default. See the code below how to name them

In the codemodule for the userform (right click on userform and select view code) copy paste the following:

Code:
Option Explicit

'///////////////   Buttons   /////////////////
Private Sub btnCancel_Click()
    Unload Me
End Sub

Private Sub btnSave_Click()
    Dim sDocPath As String, sDocName As String, sMsg As String
    Dim i As Integer
    
    ' set up path and file name
    sDocPath = tbDir
    sDocName = tbName & "_" & tbDate & ".docx"
    
    ' save the file as normal .docx
    On Error Resume Next    ' Defer error handling.
    Err.Clear
    ThisDocument.SaveAs2 FileName:=sDocPath & sDocName, _
        fileformat:=wdFormatXMLDocument
    ' Check for error, then show message.
    If Err.Number <> 0 Then
        sMsg = "Error while trying to save file." & vbCrLf & _
                "Please check filename and path"
        MsgBox sMsg, , "Error saving"
        On Error GoTo 0
    Else
        On Error GoTo 0
        ' remove macro button
        For i = ThisDocument.InlineShapes.Count To 1 Step -1
    
          With ThisDocument.InlineShapes(i)
              If .OLEFormat.Object.Name = "CommandButton1" Then
                  .Delete
              End If
           End With
        Next
            btnCancel_Click
        End If
        ThisDocument.Save
End Sub


'/////////////   Text Boxes   ////////////////
Private Sub tbDate_Change()
    'enable save button if all three fields filled
    btnSave.Enabled = Len(tbDir) * Len(tbName) * Len(tbDate)
   
End Sub

Private Sub tbDate_Exit(ByVal Cancel As MSForms.ReturnBoolean)
    'check if valid date, else set back to today
    If Not IsDate(tbDate) Then
        tbDate = Date
        Cancel = True
    End If
End Sub

Private Sub tbDir_Change()
    'enable save button if all three fields filled
    btnSave.Enabled = Len(tbDir) * Len(tbName) * Len(tbDate)
End Sub

Private Sub tbDir_Enter()
    'if user enters the textbox to change then folder picker opens
    Dim sPath As String
    sPath = GetFolder
    ' replace contents of textbox if user picked a folder
    If Len(sPath) Then tbDir = sPath
End Sub

Private Sub tbDir_Exit(ByVal Cancel As MSForms.ReturnBoolean)
    Dim sSep As String
    'check path ends with separator
    If Len(tbDir) Then
        If InStr(tbDir, "/") Then sSep = "/" Else sSep = "\"
        If Right(tbDir, 1) <> sSep Then
            tbDir = tbDir & sSep
        End If
    End If
End Sub

Private Sub tbName_Change()
    Const sInvalid As String = "*.""/\[]:;|=,<>?"
    Dim i As Integer
    
    'replace any invalid characters the user types with "_"
    If InStr(1, sInvalid, Right(tbName, 1)) Then
        tbName = Left(tbName, Len(tbName) - 1) & "_"
    End If
    'enable save button if all three fields filled
    btnSave.Enabled = Len(tbDir) * Len(tbName) * Len(tbDate)

End Sub


'////////////////////    Userform   ///////////////////////////
Private Sub UserForm_Activate()
    Dim rbRB  As MSForms.ReturnBoolean
    tbDate = Format(Date, "yyyy-mm-dd")
    tbDir = Options.DefaultFilePath(wdStartupPath)
    tbDir_Exit rbRB
End Sub

'////////////////  Support Subs / Functions  //////////////////

Function GetFolder() As String
    Dim fldr As FileDialog
    Dim sItem As String
    Set fldr = Application.FileDialog(msoFileDialogFolderPicker)
    With fldr
        .Title = "Select a Folder"
        .AllowMultiSelect = False
        .InitialFileName = Options.DefaultFilePath(wdDocumentsPath)
        If .Show <> -1 Then GoTo NextCode
        sItem = .SelectedItems(1)
    End With
NextCode:
    GetFolder = sItem
    Set fldr = Nothing
End Function

lastly you need a button in your template. From the Developers menu in Word, add a commandbutton.
Rightclick on the button to open the properties, and give the button a useful caption (for instance: Save as Docx). Then rghtclick the button again and select 'View code'
Then copy paste this into the module (overwriting the code word created)
Code:
Private Sub CommandButton1_Click()
    GetFileName.Show
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,154
Members
453,021
Latest member
Justyna P

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