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
 
hi Sydneygeek,

Code is working perfectly fine now. How can I resize my frmMenu to minimum to keep txtUser & txtLevel information in tact?
 
Upvote 0

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
If you aren't using frmMenu all the time and just want it to hold the information you can open the form hidden.
This code would do it, in the Load eevent of the form that you load at startup:
Code:
DoCmd.OpenForm "frmMenu",,,,,acHidden

Denis
 
Upvote 0
Now what I am trying to pick user id through windows login and ask user to enter password to login. I have a field in tblStaff with text format and input mask with password and my frmMenu has a textbox named txtPassword with input mask of password.

how came I only get "Login failed" message.

Private Sub Command8_Click()

Dim strPassword As String
Dim strExistPassword As String
Dim strLogin As String



strPassword = Chr(34) & Me.txtPassword.Value & Chr(34)
strLogin = Chr(34) & Me.txtuser.Value & Chr(34)


strExistPassword = DLookup("password", "tblstaff", "login = " & strLogin)
If strExistPassword = strPassword Then
MsgBox "Matched"
Else
MsgBox "Login failed"
End If

End Sub
 
Upvote 0
Denis, a Fantasic little bit of coding.
I have adapted this to also drive my reports menu thus allowing user level control of that also

Many thanks!!
 
Upvote 0
Hi,
Thanks for this tutorial is really useful, I have a couple of questions though. I am a bit rusty on Access but I have tried to construct the forms so that rather than having 3 levels of permission I have 21, basically so that I can decide what forms are allocated to each level of access. I have the code as below:

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 "2"
iAccess = 2
Case "3"
iAccess = 3
Case "4"
iAccess = 4
Case "5"
iAccess = 5
Case "6"
iAccess = 6
Case "7"
iAccess = 7
Case "8"
iAccess = 8
Case "9"
iAccess = 9
Case "10"
iAccess = 10
Case "11"
iAccess = 11
Case "12"
iAccess = 12
Case "13"
iAccess = 13
Case "14"
iAccess = 14
Case "15"
iAccess = 15
Case "16"
iAccess = 16
Case "17"
iAccess = 17
Case "18"
iAccess = 18
Case "19"
iAccess = 19
Case "20"
iAccess = 20
Case "21"
iAccess = 21
Case Else
iAccess = 1
End Select
Me.txtLevel = iAccess
Me.lstMenu.Requery

With this I get the correct level of access as allocated to the user in tblstaff (i.e. 2-21, 1 being for users no registered) and the correct forms are shown in the listbox in frmMenu. The problem I am getting though is that ever level of access is able to edit forms, I want to be able to allocate numbers 2 - 10 as read only access. I have the following code in the on Load event procedure of each form:

Private Sub Form_Load()
If Forms!frmMenu!txtLevel < 11 Then
Me.AllowEdits = False
Else
Me.AllowEdits = True
End If
End Sub

Is this possible, I seem to be going wrong somewhere!

Many thanks,
Lee
 
Upvote 0
Lee,

I'm not quite sure what is happening but you can simplify your system because all of your permission levels are numeric.
Either change the data type in the Staff table to Number and then have
Code:
If IsNothing(Me.txtUser) Then
   sPermit = 1
Else
   sPermit = GetPermission(Me.txtUser)
End If
iAccess = sPermit

or leave is as text and use

Code:
If IsNothing(Me.txtUser) Then
   sPermit = "1"
Else
   sPermit = GetPermission(Me.txtUser)
End If
iAccess = CInt(sPermit)

Maybe that will sort the permission issue on the form -- the code looks OK to me.

Denis
 
Upvote 0
Thanks Denis,

Have amended the code as you suggested with numerical rather than text fields. However everyone from level 2 - 21 has read / write access. I'd like levels 2 - 10 to be read only, is that possible or am I missing something (highly probable!)

Thanks
Lee
 
Upvote 0
Following this, have tested for someone that does not have their username listed and I get a "Run-time error '13': Type mismatch" dialogue box?

Thanks Denis,

Have amended the code as you suggested with numerical rather than text fields. However everyone from level 2 - 21 has read / write access. I'd like levels 2 - 10 to be read only, is that possible or am I missing something (highly probable!)

Thanks
Lee
 
Upvote 0
Lee, I've been mulling this over today. You only need 3 levels of permissions -- for read-only users, those with editing permissions, and administrators.
I've put together a sample database to show how it goes together. Also, if you are getting errors for non-existing users you may have left out the code for the IsNothing function.

Check out the sample and see if it helps.

Denis
 
Upvote 0

Forum statistics

Threads
1,214,971
Messages
6,122,525
Members
449,088
Latest member
RandomExceller01

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