The Problem.
There are many annoyances when designing a VBA project to run on both Windows and Mac computers. One of the most noticeable is related to the difference in screen resolution between the two platforms. On the Mac, it’s 96 dpi, where each dot represents a pixel. In Windows, screen resolution is 72 dpi (dots per inch) and each dot represents a “point”, while pixels are still 96 per inch. Confusing the issue is that VBA in Windows uses points as the measurement unit for designing UserForms, while VBA on the Mac uses pixels. The result is that without applying any correction, UserForms that come out just right in Windows are only 75% as large on the Mac, making them difficult to read.
For example, here is a UserForm designed in Windows, opened in Windows. The text might seem a bit small to me now that my eyes are getting older, but it’s still perfectly legible.
Here is that same UserForm opened on a Mac. The header text is fine, but the text in the dialog itself is too small to read comfortably.
In the past, I supported separate add-ins, one for Windows and the other for Mac. The dialogs for each were appropriately sized, and I took care of other coding idiosyncrasies in the separate files. But it’s a lot of extra work to lug around two separate versions of every file. Every adjustment you make has to be made twice, and it’s hard to remember what changes you’ve made across large projects.
The Solution: UserForms For Mac And Windows.
I have developed a simple routine that is called from each UserForm’s initialize event, which changes the size, position, and font of each control by a factor of 4/3. The text still may not always be perfect, since you can only specify whole number font sizes, so I suppose I should always round up the font size. I do make sure when I design the form that controls are more than large enough in case the text takes up extra space. Aside from this, it works pretty nicely.
Here is a UserForm designed in Windows, but which uses the resizing routine so it displays legibly on either computer. First, it is shown opened in Windows.
Below it’s shown opened on the Mac. The dialogs are equally legible, and the text came out pretty much the same. Sometimes a large block of text may not wrap the same, so if it really matters, you should hard code your line breaks by typing Ctrl+Return while entering the text.
Note: While Microsoft has substantially improved the VB editor on the Mac, you still can’t work with UserForms on the Mac. You have to build them into your file in Windows and them move the file to the Mac.
The Code.
This calls the routine from the UserForm’s code module:
Private Sub UserForm_Initialize()
#If Mac Then
ResizeUserForm Me
#End If
End Sub
The #If Mac Then
and #End If
structure indicates a section of code which is conditionally compiled. When using a Mac, the constant Mac
is True, so the code between #If
and #End If
is compiled and run, so the UserForm is resized. In Windows, this code is ignored, and the UserForm is displayed without rescaling.
The global resizing factor is placed in an appropriate place in the declarations section of a regular code module:
Public Const gUserFormResizeFactor As Double = 1.333333
And this routine in a regular code module does the resizing:
Sub ResizeUserForm(frm As Object, Optional dResizeFactor As Double = 0#)
Dim ctrl As Control
Dim sColWidths As String
Dim vColWidths As Variant
Dim iCol As Long
If dResizeFactor = 0 Then dResizeFactor = gUserFormResizeFactor
With frm
.Height = .Height * dResizeFactor
.Width = .Width * dResizeFactor
For Each ctrl In frm.Controls
With ctrl
.Height = .Height * dResizeFactor
.Width = .Width * dResizeFactor
.Left = .Left * dResizeFactor
.Top = .Top * dResizeFactor
On Error Resume Next
.Font.Size = .Font.Size * dResizeFactor
On Error GoTo 0
' multi column listboxes, comboboxes
Select Case TypeName(ctrl)
Case "ListBox", "ComboBox"
If ctrl.ColumnCount > 1 Then
sColWidths = ctrl.ColumnWidths
vColWidths = Split(sColWidths, ";")
For iCol = LBound(vColWidths) To UBound(vColWidths)
vColWidths(iCol) = Val(vColWidths(iCol)) * dResizeFactor
Next
sColWidths = Join(vColWidths, ";")
ctrl.ColumnWidths = sColWidths
End If
End Select
End With
Next
End With
End Sub
Example Workbook.
I’ve posted a simple workbook that illustrates this technique. Download it by clicking the icon below.
When you open the workbook, you’ll see a blank worksheet with three buttons.
The first button opens the Windows-only UserForm shown in the first and second figures above, in the description of the problem.
The second button opens the Windows-and-Mac UserForm shown in the third and fourth figures, in the description of the solution.
The third button opens another Windows-and-Mac UserForm which also has a simple mechanism to call the ResizeUserForm
procedure, and resize the UserForm on the fly. Here is it opened in Windows.
Enter a number in the New Form Magnification box (for example 2) and click Apply, and the form is resized accordingly.
Enter 1.333333, the ratio between pixels and points, and this is how it will be resized for the Mac, though it’s too large for Windows.
Enter 0.75, the inverse of the above, and you get a sense for how small it would be on the Mac without rescaling. Yeah, way too small.
Here is the same form opened on a Mac. Note that it’s already resized to 1.333333. Resized nicely.
Let’s see how it looks at 200%. Pretty large.
If you enter 1 in the box, you can see how the form would look without resizing.
In all of your real projects, you should apply this technique to all of your UserForms. Before deploying them to your users, you should make sure that the UserForms that look fine in Windows rescale properly on a Mac. Occasionally text wraps differently or certain other controls may need adjustments. But this eliminates the need for separate UserForms for Mac and Windows.