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,

Thank you for this tutorial.
Simple and effective.

Now I do have a question:
When I first open the database (Access 2010), I can, even without editing rights, still alter the information in the opening screen.
I am using navigation tabs to jump from one form to another.
As soon as I've jumped to another form, the rights are maintained, so how do I apply them upon start-up?

With kind regards and thank you again for the code; it is really neat,
Timo
 
Upvote 0

Excel Facts

Wildcard in VLOOKUP
Use =VLOOKUP("Apple*" to find apple, Apple, or applesauce
As soon as I've jumped to another form, the rights are maintained
Meaning: as soon as I've changed a navigation tab, the rights are applied and for the rest of the open session maintained by the dbase.
Only in the opening screen they are not. Although also in the subform of the opening navigation form this code is included:
Code:
If Forms!frmMenu!txtLevel = 1 ThenMe.AllowEdits = False
Else
Me.AllowEdits = True
End If

Any idea what I have to do to apply the rights from the beginning?
 
Upvote 0
I set up the database so that the first screen you go to is a menu / launch area, where you make selections to navigate through the database.
Because of that, the first screen is by default editable. You could instead have a hidden startup form that sets the permissions in the way that the current menu does, and then launches the first of your data forms.
That should give you the permission control from the start.

Denis
 
Upvote 0
Ok, sounds reasonable.
I'll give it a shot, this afternoon.
thank you. for the code as well, btw, it's exactly what I was looking for!
 
Upvote 0
Hi, i'm just new in this forum as i've found the tutorial that i needed for my project, but i need an alternative solution to this

in form View, the listbox shows the items but after clicking on 1 of the item in listbox it shows "compile Error: Method or Data Member not found"
and you said "It does not require the users to log in: their Windows login name is captured" << what i want is to log in on each user, and only a few user can view some forms and read only. i don't want it to be my windows login name...

Dim sForm As String, sType As String
sForm = Me.lstMenu.Column(1) <<< highlights 1stMenu The name is correct Compile Error: Method or Data Member Not Found
sType = Me.lstMenu.Column(2)
Select Case sType
Case "Form"
DoCmd.OpenForm sForm
Case "Report"
DoCmd.OpenReport sForm, acViewPreview
End Select
 
Upvote 0
The font's confusing. That is lstMenu with a lower case L, not 1stMenu with a number.

For a user-entered password solution, see this link to a sample I posted several years ago... https://www.box.com/s/vxa3w040kp3u5r77bgp8
When the password form opens use the name SH2345 and the password pear. Once a password is correctly entered the user gets the option to change it.

Denis
 
Upvote 0
The font's confusing. That is lstMenu with a lower case L, not 1stMenu with a number.

For a user-entered password solution, see this link to a sample I posted several years ago... https://www.box.com/s/vxa3w040kp3u5r77bgp8
When the password form opens use the name SH2345 and the password pear. Once a password is correctly entered the user gets the option to change it.

Denis

after clicking on the form, i still get Compile Error: Method or Data Member Not Found
 
Upvote 0
Which form?
If it's the original menu did you change the name of the listbox as I indicated above?

Denis
 
Upvote 0
Denis, I appreciate the fact that you are helping us. I am confused as to what route to take.

First, I followed all the instructions to create DB#1. I am stuck, as it doesn't work and stops at this code:
If Forms!frmMenu!txtLevel = 1 Then
Me.AllowEdits = False
Else
Me.AllowEdits = True
End If

Second, you provided a more up to data base with encryption (good), which I did not download because if it is based off a person's login, then I would not be able to test it and get it ready.

Third, you suggested an older database to use. I am afraid of using an older one, since I am on Access 2010, because it may take to much time to figure out and bring up to date.

Is there any chance there is a copy of an up-to-date working one with security built in which can be tested by one person?

I'm just not sure what route to take, as I have spent months following tutorials, yet have never ended up with a working copy to use for my 7 databases I have to upgrade to 2010, losing the old security.

My previous one that is almost done has the ability to change passwords, which is needful. Yet, I don't believe the code was quite as good. Please advise.
 
Upvote 0
Denis, I appreciate the fact that you are helping us. I am confused as to what route to take.

First, I followed all the instructions to create DB#1. I am stuck, as it doesn't work and stops at this code:
If Forms!frmMenu!txtLevel = 1 Then
Me.AllowEdits = False
Else
Me.AllowEdits = True
End If
Have you set up a user or two in the database? If so, go into the code and put a break at the first line of code for the Form_Open event on the menu form.
When you launch the form it will go into debug mode; use the {F8} key to step through, and check to see where you get the error.
Second, you provided a more up to data base with encryption (good), which I did not download because if it is based off a person's login, then I would not be able to test it and get it ready.
You can bypass the opening code by holding down the {SHIFT} key as the database launches. That lets you go into the tables, set up one or two users, and then launch again.

Third, you suggested an older database to use. I am afraid of using an older one, since I am on Access 2010, because it may take to much time to figure out and bring up to date.
Is there any chance there is a copy of an up-to-date working one with security built in which can be tested by one person?
I'm just not sure what route to take, as I have spent months following tutorials, yet have never ended up with a working copy to use for my 7 databases I have to upgrade to 2010, losing the old security.
My previous one that is almost done has the ability to change passwords, which is needful. Yet, I don't believe the code was quite as good. Please advise.
See how you go with the first two suggestions. You will always need to set up the users before testing the code; whether you use an old or new database version should not make a difference, because the code used in the database doesn't contain any superseded functions.

Denis
 
Upvote 0

Forum statistics

Threads
1,216,101
Messages
6,128,840
Members
449,471
Latest member
lachbee

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