Tutorial -- An Access menu / permissions system

SydneyGeek

MrExcel MVP
Joined
Aug 5, 2003
Messages
12,251
This is a post to put in one place an approach I use for giving different access levels to different groups of users in your Access databases. It also provides a flexible menu that adjusts to the user's permissions. It does not require the users to log in: their Windows login name is captured when they open the database. It is easy to restrict the forms. reports etc that they can use, simply by maintaining two tables; one for access levels, and one for menu items.
Parts of this have appeared on this Board before: parts are new. I hope you find it useful.

The login / menu form

You will need:

1. A table called tblStaff, with at least the fields Login and Permissions. Both are Text fields.
(a) In Login, enter the Windows login name of each user who will have ability to add or change data. Those whose names do not appear here will have read-only access to the database.
(b) In Permissions, give them values Edit or Admin

2. A form that opens as your main menu. In this example the form is frmMenu. On this form you need 2 hidden textboxes called txtUser and txtLevel.
In the Form's Load event you will need this code:

If you don't know how to do this, here's how:
Go to the form's Properties.
Click the Events tab.
Double-click the blank Load row, so you see Event Procedure.
Click the Builder (...) button to go to the code window.
Paste this code in, replacing this stuff:
Code:
Private Sub Form_Load

End Sub
With the code you copied.

Here it is:
Code:
Private Sub Form_Load()
    Dim sPermit As String
    Dim iAccess As Integer
    Dim Ctl As Access.Control
    Me.txtUser = Environ("username")
    If IsNothing(Me.txtUser) Then
        sPermit = "ReadOnly"
    Else
        sPermit = GetPermission(Me.txtUser)
    End If
    Select Case sPermit
        Case "Edit"
            iAccess = 2
        Case "Admin"
            iAccess = 3
        Case Else
            iAccess = 1
    End Select
    Me.txtLevel = iAccess
End Sub

Private Function GetPermission(sUser As String)
    If (IsNothing(DLookup("Permissions", "tblStaff", "Login='" & Forms!frmmenu!txtUser & "'"))) Then
        GetPermission = "ReadOnly"
    Else
        GetPermission = DLookup("Permissions", "tblStaff", "Login='" & Forms!frmmenu!txtUser & "'")
    End If
End Function

You give the lowest number to the lowest level of access. So, 1 is for general users whose names do not appear in the login table. They will have read-only access to forms. 2 is for those with more permissions. They will be able to add and edit data. 3 is for those with Admin privileges. They will be able to change user settings and make other behind-the-scenes modifications.

3. On each form that opens you need this in the Form_Load event:

Code:
If forms!frmMenu!txtLevel = 1 Then
   Me.AllowEdits = False
Else
   Me.AllowEdits = True
End If

A listbox to provide the menu items

This listbox will give the users the menu choices they need to navigate through the database. It is based on a table called MenuItems, with these fields:

Code:
Item        Text     The descriptive text that appears in the listbox
Level       Number   1, 2 or 3
Form        Text     The name of the form or report to open
ObjectType  Text     Form or Report
SortOrder   Number   Adjust to suit. List is sorted in ascending order.

The listbox itself is called lstMenu. It lives on the menu form that you created in the first part of this tutorial. It has these properties:

Code:
Row Source Type      Table/Query
Row Source           SELECT MenuItems.Item, MenuItems.Form, MenuItems.ObjectType FROM MenuItems WHERE (((MenuItems.Level)<=Forms!frmmenu!txtLevel)) ORDER BY MenuItems.SortOrder
Column Count         5
Column Widths        3;0;0;0;0
Bound Column         1

Populate the table and build the listbox. Check to see that it works OK. You can do that by giving yourself different levels of access in the login table, closing and re-opening the menu form and checking that the menu adjusts. Now, to make it launch the forms and reports, you will need this code in the Click event of the listbox:

Code:
    Dim sForm As String, sType As String
    sForm = Me.lstMenu.Column(1)
    sType = Me.lstMenu.Column(2)
    Select Case sType
        Case "Form"
            DoCmd.OpenForm sForm
        Case "Report"
            DoCmd.OpenReport sForm, acViewPreview
    End Select


A general function to test for "nothing"
This function below needs to go in a general code module. You will find yourself using it for much more than just the login form.

Code:
Public Function IsNothing(ByVal varValueToTest) As Integer
'-----------------------------------------------------------
' Does a "nothing" test based on data type.
'   Null = nothing
'   Empty = nothing
'   Number = 0 is nothing
'   String = "" is nothing
'   Date/Time is never nothing
' Inputs: A value to test for logical "nothing"
' Outputs: True = value passed is a logical "nothing", False = it ain't
' Created By: John L viescas 01/31/95
' Last Revised: John L viescas 01/31/95
'-----------------------------------------------------------
Dim intSuccess As Integer

    On Error GoTo IsNothing_Err
    IsNothing = True

    Select Case VarType(varValueToTest)
        Case 0      ' Empty
            GoTo IsNothing_Exit
        Case 1      ' Null
            GoTo IsNothing_Exit
        Case 2, 3, 4, 5, 6  ' Integer, Long, Single, Double, Currency
            If varValueToTest <> 0 Then IsNothing = False
        Case 7      ' Date / Time
            IsNothing = False
        Case 8      ' String
            If (Len(varValueToTest) <> 0 And varValueToTest <> " ") Then IsNothing = False
    End Select


IsNothing_Exit:
    On Error GoTo 0
    Exit Function

IsNothing_Err:
    IsNothing = True
    Resume IsNothing_Exit

End Function

Denis
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
Wayne, if you can wait a little bit longer, just a few days. I'm about to finish a generic login system (GLIS) for Access.
With GLIS you can set permissions on form level and control level as well.

For each role you can define the next properties

on form level
- data entry
- Allow edits
- Allow deletions
- Allow additions

on control level
- visible
- enabled
- locked (unless the control is a button)
 
Last edited:
Upvote 0
As promised, I've uploaded a Beta Beta Beta version of a generic login system for Access.

GLIS Download

The default password you need for testing is Welcome01 (case sensitive)

As a bonus encrypted password security is added.

Please give feedback for further development.
 
Upvote 0
Excellent tutorial, Denis

I have a suggestion, hope you don't mind me adding on ...

instead of this:
If forms!frmMenu!txtLevel = 1 Then
Me.AllowEdits = False
Else
Me.AllowEdits = True
End If

which will prevent users from picking items in unbound controls too, I prefer to set the Locked property of each control. Optionally I may set the Enabled property too.

Locked prevents a user from making any changed if it is True (unlike Excel where you also have to Protect). Enabled makes that information like an image where you cannot click in the control to copy and paste either.

the TAG property is handy to use to control processing. For instance, put this in the Tag property for data controls
~Data~

Tilde's are used to delimit so other things can be in the tag without interfering

Here is general code that checks each control in the Detail section of the form to see if its tag contains the specified value. If it does, then it check to see if True or False was passed and sets Locked and Enabled accordingly.

Code:
Function LockUnlockDetailControlsTag( _
   pForm As form_
   , pBoo As Boolean _
   , pTag As String _
   , optional pControlFocus As control _
   ) as byte
 'Crystal, strive4peace, 1/7/08

   Dim ctl As Control  
 
   'if we are locking and disabling controls then move focus
   if pBoo then 
      pControlFocus.SetFocus
   end if

   On Error goto Proc_Err
 
   'this is limited to controls in the detail section
   '   use pForm.Controls to test everything
   For Each ctl In pForm.Detail.Controls
 
      If InStr(ctl.Tag, pTag) > 0 Then
 
         ctl.Locked = pBoo
         ctl.Enabled = not pBoo 'you may want to leave controls enabled
 
      End If
 
   Next ctl
 
Proc_Exit:
 
   If Not ctl Is Nothing Then Set ctl = Nothing
   Exit Function
 
Proc_Err:
   MsgBox Err.Description, , _
        "ERROR " & Err.Number _
        & "   LockUnlockDetailControlsTag"
 
   Resume Proc_Exit

   'if you want to single-step code to find error, CTRL-Break at MsgBox
   'then set this to be the next statement
   Resume
 
End Function

then in code behind your mainform, to lock controls:

LockUnlockDetailControlsTag Me, true,"~Data~", me.controlname_SetFocus

This code requires that a safe control to move to be specified since disabling a control that has the focus will throw an error. I have other versions of this code where this is optional -- in that case, use a string and pass the control name as an optional parameter and use pForm(pControlNameFocus).SetFocus

an advantage of passing a string is if your form has no record showing, you will avoid an error that will happen when passing a control reference and there is no control. I use control in examples to show how easy it is to do and to simplify the logic

If the code is not locking controls then the focus is not changed. I added a comment to the line to flip Enabled since it is not necessary. That being the case, it would be best to pass an optional parameter for the control that will take the focus.

I modified the above code to add a little more flexibility:
Code:
Function LockUnlockControlsTag( _
   pForm As Form _
   , pBoo As Boolean _
   , pTag As String _
   , Optional pControlFocus As String = "" _
   ) As Boolean
 'Crystal, strive4peace, 1/7/08, 121121
 
   On Error GoTo Proc_Err
   LockUnlockControlsTag = False
   
   Dim ctl As Control
 
   'if a controlname is specified for the focus, then move it
   If Len(pControlFocus) > 0 Then
      pForm(pControlFocus).SetFocus
   End If
 
   'loop through all controls in the Detail section
   '   use pForm.Controls to test everything
   For Each ctl In pForm.Detail.Controls
 
      'see if control contains the specified text in the TAG
      If InStr(ctl.Tag, pTag) > 0 Then
 
         ' set the Locked property according to what was passed
         ' only change if necessary
         If Not ctl.Locked = pBoo Then ctl.Locked = pBoo
         ' commented because you may want to leave controls enabled
         ' or have another test for enabled
         ' ctl.Enabled = not pBoo
 
      End If
 
   Next ctl
 
   LockUnlockControlsTag = True
   
Proc_Exit:
   On Error Resume Next
   If Not ctl Is Nothing Then Set ctl = Nothing
   Exit Function
 
Proc_Err:
   MsgBox Err.Description, , _
        "ERROR " & Err.Number _
        & "   LockUnlockControlsTag"
 
   Resume Proc_Exit

   'if you want to single-step code to find error, CTRL-Break at MsgBox
   'then right-click on "Resume" and choose --> Set Next Statement
   'press F8 to resume with the line that threw the error so you can inspect it
   Resume
 
End Function

in this case, you don't need to specify a control to take focus

LockUnlockControlsTag Me, true, "~data~"

So, hooking this into the code you posted:

Code:
    Select Case sPermit
        Case "Edit"
            LockUnlockControlsTag Me, false, "~data~" 'don't lock or move focus
        Case "Admin"
            LockUnlockControlsTag Me, false, "~data~" 
        Case Else
    'lock controls and set focus to a control to find records
            LockUnlockControlsTag Me, true, "~data~", "cbo_Find"
    End Select

Use the form Open event

There is no need to do anything in the Load event or use Me.txtLevel. Do everything for users and permissions in the Open event. If the user does not even have privileges to see it, then Cancel opening the form

the admin may be able to change more controls -- sometimes you may wish to call a popup password prompter on control BeforeUpdate events. This enables an admin to use any user's interface with their super privileges. You can also create a invisible command button to act as a secret hotspot so an admin can flip the privileges on any record. Use the current event to set them back or rely on the admin to do it ...

the routine returns True if successful and False if not, in case you want to test it
 
Upvote 0
>I am working on Access 2010 and it seemed to like "!" rather than "."

do NOT do this! Let the compiler check your references -- otherwise the users will get errors when they run it!
 
Upvote 0
adding on ...
! means member. Fields are members of a collection such as fields in a table
. means property of an object ... if controlnames are the same as the fieldname they contain, this is better

although controlname is not a property of me.forms, me.forms.controlname really means me.forms.controls("controlname") since controls is the default collection'

You can use ! or . when referring to fields that are in the source of a form, report, or query. You must use ! when referring to fields in a recordset. Using . is an advantage when coding because the compiler checks more :)

I ALWAYS name my controls the SAME as the fieldname they contain ... many will tell you to use TXT or CBO or prefix the controlname; I do not do this with bound controls because it adds unnecessary complexity; Access will figure it out ;)
 
Last edited:
Upvote 0
When I want to not Enable, I usually just LOCK so the user can't change but can still select and copy. When you do not enable, the user cannot select and copy it either ...

Command buttons do not have a Lock property (only controls that can hold data have that) so the only choice is to not enable

> "on the Form ... fields"

terminology correction: forms do not have fields; they have controls which can contain fields
 
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,212
Members
453,023
Latest member
alabaz

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