Microsoft Excel

Ron de Bruin
Excel Automation

Microsoft MVP Program

Create/use custom or default sheet templates in Mac Excel

Note : If you use Excel for Windows read the information on this page.

If you want to insert a new specific worksheet to your workbook with a nice layout and maybe a few formulas on a regular basis then you have two options.

Make a copy each time of a clean worksheet with your layout

1: Select the sheet that you want to copy
2: Right click on the sheet tab and choose "Move or Copy..."
3: Check the "Create a copy" checkbox
4: Be sure that the “To book” dropdown show the name of your file
5: Press OK

Or hold the Alt key down and drag the sheet tab to the right or left with your mouse.
When you release the mouse button you will see the copy of the sheet.

 

Use a Sheet template(xlt, xltx or xltm)

How do I create one:
1: Open a new workbook and delete all worksheets except the first one.
2: Change all the things you want in this worksheet
3: Then use File>Save As to save the file with the name you want as a Template (xlt, xltx or xltm). When you save as a template it automatically want to save in the default template folder.

How do I find the template folder in 2011 :

With code you can find the correct path in Excel 2011 with this code line
MsgBox Application.TemplatesPath & "My Templates"

On my English Mac the folder location in Finder is : Macintosh HD:Users:RDB:Library:Application Support:Microsoft:Office:User Templates:My Templates

Note in Excel 2011 in will make the folder "My Templates" in your TemplatePath automatic the first time you save a file as template. In every language version it is named "My Templates"

Note : The library folder is a hidden folder, press the Alt key when you click on Go in the Finder menu to see/open this folder.

 

How do I find the template folder in 2016 :

With code you can find the correct path in Excel 2016 with this code line
MsgBox Application.TemplatesPath

“You see the string .localized appears twice in the msgbox (/User Content.localized/Templates.localized/). You don’t see these in the Finder because by default the Finder suppresses extensions; while VBA shows the raw folder names, in English.”

On my English Mac the folder location in Finder is : /Users/rondebruin/Library/Group Containers/UBF8T346G9.Office/User Content/Templates

On my Dutch Mac in Finder User Content/Templates show up as Gebruikersinhoud/Sjablonen

Note : The library folder is a hidden folder, press the Alt key when you click on Go in the Finder menu to see/open this folder.

 

How do I insert a custom worksheet template in my workbook:

Note : As far as I know there is no option in the UserInterface like in Excel for Windows to insert custom sheet templates in Excel for the Mac. But I hope I am wrong. If you know a way please let me know so I can update this page. Note: when you change the default Excel worksheet you can use the normal options in the userinterface to insert worksheets, read the last section of this page for more information.

But you can do it with VBA code if you want. Test the two basic examples below in Mac Excel 2011 and Mac Excel 2016:

Example to select the template you want to insert in your workbook :

With the macro example below you can select the template that you want to insert, you do not have to change anything in the macro before you try it.

Sub Insert_Sheet_Template_Mac_2()
    Dim MyPath As String
    Dim MyScript As String
    Dim MyFile As String

    If Val(Application.Version) < 15 Then
        MyPath = Application.TemplatesPath & "My Templates" & Application.PathSeparator
    Else
        MyPath = MacScript("return POSIX file (" & _
                Chr(34) & Application.TemplatesPath & Chr(34) & ") as alias")
    End If

    MyScript = _
    "set applescript's text item delimiters to {ASCII character 10} " & vbNewLine & _
    "set theFiles to (choose file of type {""org.openxmlformats.spreadsheetml.template"", " & _
    """org.openxmlformats.spreadsheetml.template.macroenabled"",""com.microsoft.excel.xlt"" } " & _
    "with prompt ""Please select the template worksheet that you want to insert"" default location alias """ & _
    MyPath & """ multiple selections allowed false) as string" & vbNewLine & _
    "set applescript's text item delimiters to """" " & vbNewLine & _
    "return theFiles"

    On Error Resume Next
    MyFile = MacScript(MyScript)
    On Error GoTo 0

    If MyFile <> "" Then
        If Int(Val(Application.Version)) = 15 Then
            MyFile = MacScript("return POSIX path of (" & _
                               Chr(34) & MyFile & Chr(34) & ")")
        End If
        Sheets.Add Type:=MyFile
    End If
End Sub

The example below will insert the template MySheetTemplate.xltx after the last sheet in your workbook. You can use this macro for example if you want to insert a new worksheet based on this template every day. Be sure you have saved a sheet template with the name MySheetTemplate.xltx in the default template folder before you test the code.

Sub Insert_Sheet_Template_Mac_1()
    Dim sh As Worksheet
    Dim shName As String
    Dim TemplatesPath2016 As String

    'Name of the sheet template
    shName = "MySheetTemplate.xltx"

    'Insert sheet template
    With ThisWorkbook
        If Val(Application.Version) < 15 Then
            Set sh = Sheets.Add(Type:=Application.TemplatesPath & "My Templates" & _
                Application.PathSeparator & shName, after:=.Sheets(.Sheets.Count))
        Else
            TemplatesPath2016 = MacScript("return POSIX path of (" & _
                    Chr(34) & Application.TemplatesPath & Chr(34) & ")")
            Set sh = Sheets.Add(Type:=TemplatesPath2016 & shName, _
            after:=.Sheets(.Sheets.Count))
        End If
    End With
End Sub

If the sheet name in the template is "ron" the first time the name of the sheet is "ron" the second time the name is "ron(2)" and the third time "ron(3)" and .....

 

Change the Default Excel sheet template

In Excel 2011 and 2016 you can insert a new default worksheet like this:

If you want to change the settings of this worksheet you can create your own default sheet template:

Every worksheet you insert now is based on this worksheet template.

Important : You must remove the extension of the file name so only Sheet is left as template name. Note: If you not see file extensions use Finder>Preferences..Advanced to show them(first checkbox)

Where is the Excel Startup folder in 2011 ?

Open a new finder window and use Go>Go to Folder in the menu bar and paste in the path below to open the default Excel sheet template folder in Finder. Do not forget to copy the / in front, it automatically place the harddisk name in front of the other folders in the path.

/Applications/Microsoft Office 2011/Office/Startup/Excel

With code you can find the correct path with this code line
MsgBox Application.StartupPath

 

Where is the Excel Startup folder in 2016 ?

Note : In Excel 2016 the path is not the same as in 2011, use this code line to find the correct folder for 2016 to copy the Sheet template in : MsgBox Application.StartupPath

“You see the string .localized appears twice in the msgbox (/User Content.localized/Startup.localized/). You don’t see these in the Finder because by default the Finder suppresses extensions; while VBA shows the raw folder names, in English.”

On my English Mac the folder location in Finder is : /Users/rondebruin/Library/Group Containers/UBF8T346G9.Office/User Content/Startup/Excel

On my Dutch Mac in Finder User Content/Startup show up as Gebruikersinhoud/Opstarten

Note : The library folder is a hidden folder, press the Alt key when you click on Go in the Finder menu to see/open this folder.

 

Workbook template

Tip: you can also make a custom default workbook if you want and add it in your Startup folder, you must name the template file Workbook (remove the extension).