Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Synchronized Floating popup Form

Synchronized Floating Popup Form.

This form is designed specifically for inquiry purposes (not for data entry). The Source Data Table has several fields, and the information in them can be categorized into different groups for viewing.

For example, the Employees Form in the Northwind.mdb sample database is divided into two sections: Company Information and Personal Information. The Company Information fields are placed on the first page of a Tab Control, and the Personal Information fields are located on the second page, which remains hidden until the user clicks its tab to bring that data into view. Typically, since the Company Information section is accessed or updated more frequently, it is kept in full view, and the Personal Information section stays tucked away in the background, as it is not always viewed or edited.

We will design them differently, an interesting trick with two separate stand-alone Forms, without linking them together as the Main Form and the Sub-Form. Company Information on one Form and Personal Information on a separate Form, but both will have the source record from the Employees table. Why two Forms? Whenever the Personal Information of an employee or several Employees is to be viewed, then open the Form and keep both forms synchronized to view information of an employee(s) on both forms.

Let us name them as EmployeeMain and EmployeeSub Forms. They will remain as two independent Forms. A sample image of both Forms in running mode is given below:


The Trick Designs Plan

The trick is that when we open the EmployeeMain Form, it will show only the Company Info alone (no trick here). We will move a few records forward using the Record Navigation Button, and at this point, we would like to see the Personal Info part of the current record. We will click on a Command Button to open the EmployeeSub Form with the Personal Info of the current record on the EmployeeMain Form. From this point onwards, the records on both Forms move forward or back, and both ways are synchronized when moving to the Next or Previous records on the EmployeeMain Form, even though they are two separate Forms.

The EmployeeSub Form is defined as a Pop-up Form (or its Pop-up Property value is set to Yes) to float it above the EmployeeMain Form or any other Form open in the Application Window, provided you don't open another Pop-up Form. If you don't want the EmployeeSub Form, then close it and open it again when needed using the Personal Info Command Button on the EmployeeMain Form. When you close the EmployeeMain Form, this action will close the EmployeeSub Form if it is running.

  1. We can very easily design these two Forms by importing the Employees Table and Employees Form from C:\Program Files\Microsoft Office\Office11\Samples\Northwind.mdb Database. If you have not used these forms for any other examples given on this site, you may import them into your database now.

  2. Open the Employees Form in Design View.

  3. Click on the Form and drag the mouse over all Controls on the Company Info Tab except the Photo (if you want it, you may select that too) and the Command Button controls.

  4. Select Copy from the Edit Menu.

  5. Click on the Employees Table, select Form from the Insert menu, and select Design-View from the list of options displayed to create a new Form.

  6. Click on the Detail Section of the Form and select Paste from the Edit Menu to place the copied fields of the Employees Form onto the new Form.

  7. If the Form Header/Footer Sections of the Form are not visible, then select Form Header/Footer from the View Menu.

  8. Copy and paste the Text Control with the employee name expression from the Header Section of the Employees Form into the Header Section of your Form. Change the Font Color to Red or some other color you like.

  9. Create a Command Button in the Detail Section below the data fields.

  10. Display its Property Sheet (View -> Properties).

  11. Change the Name Property Value to cmdPersonalInfo and the Caption Property Value to Personal Info.

    NB: You must be careful with the names of Forms and Controls I suggest here because they are used in the Programs. If you give them a different the trick may not work as expected after completion.

  12. Create a Command Button at the Footer Section of the Form.

  13. Change the Name Property value to cmdClose and the Caption Property Value to Close.

  14. Display the Form's Property Sheet. Click on the left top corner of the Form where a black rectangle is shown, at the intersection of the horizontal and vertical design guide (scales), to select the Form's Property Sheet, if it is not the current one.

  15. Change the Caption Property Value to Company Info.

  16. Display the VBA Code Module of the Form (Alt+F11). Copy and paste the following code into the Code Module.

    The Form Module Code

    Option Compare Database
    Option Explicit
    Dim strSQL As String
    
    Private Sub cmdClose_Click()
       DoCmd.Close
    End Sub
    
    Private Sub cmdPersonalInfo_Click()
    If IsLoaded("EmployeesSub") Then
       strSQL = "SELECT Employees.* FROM Employees "
       strSQL = strSQL & "WHERE ([EmployeeID] = " & Me![EmployeeID] & ");"
       Forms("EmployeeSub").RecordSource = strSQL
       DoCmd.SelectObject acForm, "EmployeeSub", False
    Else
       DoCmd.OpenForm "EmployeeSub", acNormal, , "[Employeeid] = " & Me![EmployeeID], acFormReadOnly, acWindowNormal
    End If
    
    Forms("EmployeeMain").ActiveControl.SetFocus
    
    End Sub
    
    Private Sub Form_Close()
        DoCmd.Close acForm, "EmployeeSub"
    End Sub
    
    Private Sub Form_Current()
    If IsLoaded("EmployeeSub") Then
       strSQL = "SELECT Employees.* FROM Employees "
       strSQL = strSQL & "WHERE ([EmployeeID] = " & Me![EmployeeID] & ");"
       Forms("EmployeeSub").RecordSource = strSQL
       DoCmd.SelectObject acForm, "EmployeeSub", False
       Forms("EmployeeMain").SetFocus
    End If
    
    End Sub
    
    Private Sub Form_Open(Cancel As Integer)
    DoCmd.Restore
    End Sub
    
  17. Save the Form with the name EmployeeMain.

  18. Repeat the process from Step 3 to Step 8 for transferring information from the Personal Info Tab of the Employees Form to a new Form.

  19. Display the Form Header/Footer Section of the Form (View ->Form Header/Footer).

  20. Create a Command Button and change the Name Property Value to cmdClose and the Caption Property Value to Close.

  21. Display the Form's Property Sheet.

  22. Change the following Property Values as given below:

    • Caption = Personal Info
    • Default View = Single Form
    • Allow Additions = No
    • Allow Deletions = No
    • Data Entry = No
    • Record Selectors = No
    • Navigation Buttons = No
    • Dividing Lines = No
    • Auto Resize = Yes
    • Pop Up = Yes
    • Border Style = Dialog
    • Allow Design Changes = Design View Only.
  23. Display the Code Module of the Form (Alt+F11).

  24. Copy and paste the following code into the Code Module.

    Private Sub cmdClose_Click()
            DoCmd.Close acForm, Me.Name
    End Sub
    
  25. Save the Form with the name EmployeeSub.

    We need a small program to check whether the EmployeeSub Form is in an Open state or not before attempting to refresh its source data and bring it into a visible state.

    The Standard Module Code

  26. Copy and Paste the following Code into a Global Module (Standard Module) and save the Module:

Public Function IsLoaded(ByVal strFormName As String) As Boolean
Dim j As Integer

On Error GoTo IsLoaded_Err

IsLoaded = False
For j = 0 To Forms.Count - 1
    If Forms(j).Name = strFormName Then
       IsLoaded = True
       Exit For
    End If
Next

IsLoaded_Exit:
Exit Function

IsLoaded_Err:
IsLoaded = False
Resume IsLoaded_Exit
End Function

The Demo Run

  1. To try out your creation, open the EmployeeMain Form and click on the Record Navigation Control to advance a few records forward.

  2. Click on the Personal Info Command Button. The EmployeeSub Form will open, displaying the Personal Information that belongs to the same employee on the main Form. Check the Name of the Employee appearing on top of both forms.

  3. Now, try advancing records on the main form forward or back to the record navigation control. You will see that the corresponding personal information on the EmployeeSub Form also belongs to the same record on the main form.

  4. If you close the EmployeeMain Form while the EmployeeSub Form is open, both will be closed.

Download Demo Database.

You may download the sample database from the Download Link given below and give it a try before you design one of your own to understand the trick:


Share:

Forms and Custom Properties

Introduction

Searching for and locating a record in a Form is quite easy using the Edit → Find (Ctrl + F) option on a specific field value. However, this method retrieves only the first matching record, even when multiple records share the same search text. In practice, we often need to filter records that match criteria across fields, for example, finding all Sales Representatives of Northwind Traders who are located in the City of London.

Let’s create a simple method to find and display all records from the Employees table that match both the City and Title fields.

If you haven’t already done so, import the Employees sample table from:
C:\Program Files\Microsoft Office\Office\Samples\Northwind.mdb.

  1. Next, create a temporary table named temp_param with two text fields: City and Title.

  2. Add a single record with the following values:

    • City: London

    • Title: Sales Representative

  3. Now, design the Main Form using this table as its Record Source and place both fields in the Header Section of the Form.

  4. For a better and more user-friendly approach, create two Combo Boxes instead of directly placing the fields on the Form. Populate these Comboboxes using distinct values from the City and Title fields of the Employees table. To do this, create two Select Queries that group these field values, and then use them as the Row Source for the Combo Boxes. Follow the steps outlined below.

  5. Query Name: cboCityQ

    SELECT Employees.City
    FROM Employees
    GROUP BY Employees.City;
    

    Copy and paste the above SQL String into a new Query's SQL editing window and save it with the name cboCityQ. Create a second Query with the SQL string given below and save the Query with the name cboTitleQ.

  6. Query Name: cboTitleQ
    SELECT Employees.Title
    FROM Employees
    GROUP BY Employees.Title;
    
  7. Create a Combo-Box in the Header Section of the Main Form using cboCityQ as source data and select City as Control Source.

  8. Create another Combo-Box, use the cboTitleQ Query as source data, and select Title as Control Source.

  9. Name the City field Combo-Box, as cboCity, and the Title field, Combo-Box name as a cboTitle.

  10. Design a Datasheet form on the Employees Table and save the Form with the name Employees_Sub.

  11. Insert the Employees_Sub Form as a Sub-Form in the Detail Section of the Main Form.

  12. Click on the Sub-Form, display the Property Sheet (View -> Properties), and set the following Property values as shown below:

    Link Child Fields = City; Title

    Link Master Fields = cboCity;cboTitle

  13. Now you can select the City and Title values from the combo boxes, and all the matching records will immediately show up in the Datasheet Sub-Form.

Database Sharing Issues

If the database is used by a single user (or opened with exclusive access by one user on the network), the above method will work perfectly without any issues. However, the situation changes when the database is shared among multiple users on a network.

Even though each user opens a separate instance of the Main Form on their own machine, they are all sharing the same underlying table to set their search criteria at the same time. This shared access can lead to conflicts, because when one user refreshes the Main Form and updates the record in the temp_param table, it can overwrite or interfere with another user’s search parameters.

As a result, both users may end up with unexpected or incorrect results when the form is refreshed and the shared parameter table is modified simultaneously.

A Workaround Method

A workaround to this problem is to use Unbound Text Boxes/Combo-Boxes on the Main Form and not to use the temp_param Table at all to store the values selected from cboCity and cboTitle Combo-Boxes.

Users can set the Values on the Unbound Text Box/combo box on their own instance of the Form without conflicts.

This method also has some, not-so-serious, side effects. When the User opens the Main Form, it will be empty till they select some values from the unbound combo boxes. We can rectify this to a certain extent by creating two Custom Properties on the Main Form. Save the last used value from the combo box controls into these custom properties when the Form closes, and restore them when the Form opens again.

Why, I said to a certain extent, because if several Users are sharing the Main Form, then the Custom Property values are saved by each User in the Main Form (when he/she closes their instance of the Form) and will retain only the value saved last. But all the Users who open the Main form next time will be presented with the records related to the Custom Property Values saved last. But this is not a big issue because most probably next time when they open the Form, they may require records for different criteria and can change it too.

Creating Custom Properties on Form

To implement this method, first, we must create the Custom Properties: prpCity and prpTitle on the Main Form and save some initial values into them. We can do this only with VBA Code. The Sample Code is given below:

Public Function CustomProperty()
Dim db As DAO.Database, doc As Document, prp As Property

Set db = CurrentDb
Set doc = db.Containers("Forms").Documents("Main")
'creates the Custom Property with Name, data type and initial value
Set prp = doc.CreateProperty("prpCity", dbText, "London")

'add the new Custom Property to the Properties collection of the Form Main
'NB: This will not appear in the Property Sheet of the Form

doc.Properties.Append prp
Set prp = doc.CreateProperty("prpTitle", dbText, "Manager")
doc.Properties.Append prp
doc.Properties.Refresh
End Function

Here, you can see that the reference to the Main Form is addressed differently than the usual method of Forms_Main or Forms![Main] or Forms("Main"), etc.. The Forms group is addressed as Container; a member of the Containers (Tables, Forms, Reports, etc.) The group and the Main Form are addressed as a Document, a member of the Documents Collection. To learn more about Containers and Documents, visit the page with the Title: Saving Data on Forms not in a Table.

Since this is a one-time exercise, you can copy the above Code into a Global Module (Standard Module) and run the Code directly by placing the cursor in the middle of the Code and pressing F5 (Run).

If you attempt to run the Code a second time, it will show Errors indicating that the Custom Properties with the given name are already present in the Form.

The next step is to use these Custom Properties within the Form_Close() and Form_Load() event procedures. In the Form_Close() event, we will save the current values from the Combo Box controls in the Form’s Custom Properties. Then, in the Form_Load() event, these saved values will be restored automatically into the corresponding Combo Box controls when the Form is opened again.

This ensures that the user’s last-selected filter criteria are remembered and re-applied the next time the Form is opened, providing a smoother and more user-friendly experience.

Saving Combo Box Value into Custom Property

The following Code saves the combo box contents into prpCity and prpTitle custom properties on the Main Form when the Form is closed:

Private Sub Form_Close()
Dim db As Database, doc As Document, prp As Property

On Error GoTo Form_Close_Err

Set db = CurrentDb
Set doc = db.Containers("Forms").Documents("Main")

'Save the current values from the combo boxes into the custom properties
doc.Properties("prpCity").Value = Me![cboCity]
doc.Properties("prpTitle").Value = Me![cboTitle]

Form_Close_Exit:
Exit Sub

Form_Close_Err:
MsgBox Err.Description, , "Form_Close()"
Resume Form_Close_Exit
End Sub

Restoring Value from Custom Property

The following Code restores the cboCity and cboTitle values when the Main Form opens for Users again:

Private Sub Form_Load()
Dim db As Database, doc As Document, prp As Property

On Error GoTo Form_Load_Err

Set db = CurrentDb
Set doc = db.Containers("Forms").Documents("Main")

'Set the Combobox values from the Custom Property values saved earlier

Me![cboCity] = doc.Properties("prpCity").Value
Me![cboTitle] = doc.Properties("prpTitle").Value

Form_Load_Exit:
Exit Sub

Form_Load_Err:
MsgBox Err.Description, , "Form_Load()"
Resume Form_Load_Exit
End Sub

How about positioning a particular record on the Form that you worked on last time, as the current record when the Form opens? Click here to find out.

Share:

ControlTip Text and Time Delay

Introduction

Most of the controls on a Form—such as Command Buttons, Labels, Text Boxes, and others—have a ControlTip Text property. This property can hold text up to a maximum length of 255 characters, which can be set either manually during design time or programmatically through VBA.

The text entered here is displayed when the mouse pointer hovers over the control for a few seconds. This is particularly useful for providing quick hints or instructions to the user, such as prompting them to click or double-click a Control to execute a program or macro attached to it.

Similarly, Toolbar Buttons in Access also feature this capability through their ScreenTip property (which functions the same way as ControlTip Text). These small pop-up hints guide users by explaining what each button does or by suggesting keyboard shortcuts.

For example, when you point to the Copy toolbar button, the tooltip displays “Copy (Ctrl+C)”, indicating that you can either click the button or press Ctrl+C to copy the selected text or control.

This brief delay before the tooltip appears is intentional—it assumes that if the user leaves the mouse resting on a control, they may be uncertain about its function. The tooltip then provides helpful information about the control’s purpose or action, improving the overall user experience.

Our own Method without Time Delay

Here, we will implement a new method for the controls on the Main Switchboard (Control Screen)—such as Command Buttons and List Boxes—to provide immediate feedback to the user, without the time delay inherent in the ControlTip Text property.

There is another property, called Tag, located near the ControlTip property in the control’s property sheet. Its function is not predefined and is completely free for custom use. The value stored in the Tag property does not affect the control’s behavior or interact with other properties in any way. In fact, you can store up to 2048 characters of text here—enough to write a short description or even a mini story!

We will use this Tag property creatively on the controls of the Main Switchboard in a sample database. The idea is to instantly display helpful hints or action clues to the user—for example, what each control does or what kind of action (click or double-click) should be performed to run a program or macro associated with that control.

To implement this, open the Property Sheet (via View → Properties) for each control on the Switchboard, and type your desired descriptive text into the Tag property. Then, place a Label control at the bottom of the form (give it a dark background or any color you prefer) to serve as the “instant help bar.”

When the mouse pointer moves over a control with a Tag value set and programmed, the Tag’s text value appears immediately in that label—without any delay—offering the user quick, context-sensitive information.

An image of a sample Main Switch Board with the above trick is given below:


Using the Mouse Move Event

A Label with a dark background (let us call it LBLTIP) is placed at the bottom of the design to display the clues when the Mouse moves over the controls above. The example text shown in the image was saved in the Tag Property of the ListBox along with the Forms' Names.

To display the clue and to remove it when the Mouse moves out of the Control, we need to run a few lines of VBA Code at two places. On Mouse Move Event Procedure of the Control, as well as at the Detail Section of the Form, to remove the text and replace it with some general message text or a zero-length string to keep it empty.

The sample code in the On Mouse Move Event Procedure of the Reports Command Button is given below. It displays Open Report SwitchBoard in the LBLTIP label Caption text at the bottom of the form when the Mouse is moved over the Command Button.

Private Sub cmdRpt_MouseMove(Button As Integer, Shift As Integer, X As Single, Y As Single)
If Me.LBLTIP.Caption = Me.cmdRpt.Tag Then
    Me.LBLTIP.Caption = Me.cmdRpt.Tag
End If
End Sub

When the Mouse moves out of the Command Button and touches the empty area of the Detail Section of the Form, the LBLTIP Caption changes to Welcome User: Admin (the current MS-Access User Account name) displays and stays there till the mouse moves over to another Control on the Form.

The VBA Code in the Detail Section, On Mouse Move Event Procedure is given below:

Private Sub Detail_MouseMove(Button As Integer, Shift As Integer, X As Single, Y As Single)

Dim strtag As String

strtag = "Welcom User: " & CurrentUser

If Me.LBLTIP.Caption <> strtag Then
    Me.LBLTIP.Caption = strtag
End If

End Sub

Limiting the Mouse Move Event

Even though the Detail Section Mouse Move Event Procedure has no change in the Code, repeating all three lines of code for each control is excessive work. The IF... Then the Statement is used to test and prevent setting the LBLTIP Caption value repeatedly.

We can implement this feature with just a single line of code if we define a common routine and place it in a Global Module (Standard Module). Once the routine is in place, it can be called from any control’s event procedure with the necessary parameters, keeping your codebase clean and reusable.

A sample function to achieve this is shown below:

Copy the following VBA Code and save it in a Standard Module:

Public Function ControlTip(ByVal frmName As String, Optional strtext As String = "Welcome User: ", Optional xswitch As Integer = 0)
On Error GoTo ControlTip_Err
With Forms(frmName).Controls("lblTip"
    Select Case xswitch
        Case 1
            If .Caption <> strtext Then
                .Caption = strtext
            End If
        Case Else
            If .Caption <> strtext Then
                .Caption = strtext & CurrentUser
            End If
    End Select
End With

ControlTip_Exit:
Exit Function

ControlTip_Err:
MsgBox Err.Description, , "ControlTip()"
Resume ControlTip_Exit
End Function

The above Function has three Parameters:

  1. Name of the Form where the Function is called.

  2. The LBLTIP.Caption display text. This will be taken from the Tag Property Value of the Control. This parameter is defined as Optional so that this can be called without a value at the Form level (in our example from the Detail Section) to display the welcome message after removing the earlier contents.

  3. The Optional xswitch parameter value is used for display choices. The Value of 1 will display the Text value passed through the Second Parameter, or else it will display a welcome message to the User, replacing the earlier text in the LBLTIP Caption Property.

With the above Function, we can simplify the first two Sub-Routines as given below:

Private Sub cmdRpt_MouseMove(Button As Integer, Shift As Integer, X As Single, Y As Single) 

ControlTip Me.Name, Me.cmdRpt.Tag, 1

End Sub

Private Sub Detail_MouseMove(Button As Integer, Shift As Integer, X As Single, Y As Single)

    ControlTip Me.Name
    
End Sub

 Demo Database Download

You can download the sample database (Access 2000 Version) from the link given below and try it out.

 

Download Demo ControlTip2k.zip

Share:

External Files List in Hyperlinks

Introduction

    We have seen that we can open and work with external data sources, dBase Tables, Excel Databases, and AS400 (iSeries) tables directly without linking them permanently to MS Access, as demonstrated in earlier articles.

    In this tutorial, we will explore a different kind of external access — working with files on your disk, regardless of their type (Word documents, Excel workbooks, PDFs, images, etc.), and displaying them on an Access Form as clickable hyperlinks that open in their respective default applications.

    To achieve this, we will:

    1. Browse and select files from Disk using the Common Dialog Control (the File Browser).

    2. Store the file paths in a Table for easy retrieval.

    3. Display the list of files as hyperlinks on a Form.

    4. Open each file in its associated program (Word, Excel, Adobe Reader, etc.) simply by clicking the hyperlink.

    This approach is useful in scenarios such as:

    • Managing project-related documents from within Access.

    • Providing quick access to scanned images or PDFs attached to records.

    • Creating document libraries, training materials, or archives where Access acts as a front-end to organize and launch files efficiently.

    Before diving into the implementation, let us first understand how the Common Dialog Control (File Picker) works and how we can use it to browse and select files dynamically.

  • Opening External Data Sources
  • Opening dBase Files Directly
  • Display Excel Value Directly on Form
  • Opening an Excel Database Directly
  • Database Connection String Properties
  • Access Live Data in Excel
  • Access Live Data in Excel-2
  • Source ConnectStr Property and ODBC
  • But all of them fall into only one category, data files.

    Designing the Files List Form.

    To answer the above queries, we will create a Form with a Datasheet Sub-Form and with a few simple controls to take a listing of all frequently used files of your choice (Text Files, Word Files, Excel Files, or  Files of all Types) from the Disk and display them in a list of Hyperlinks. When you like to open and work with a file in its parent Application, simply click on the hyperlink to select and open the file.  An Image of the sample Form is given below:

    Finding Files in Folders

    Click the Create File Links button to open the File Browser (the Common Dialog Control). Browse to locate your desired files; you may select one or more, and click OK to bring their references into the List Control as clickable Hyperlinks.

    The File Path Name for each file is displayed in the adjacent control to the right of the hyperlink. This makes it easy to identify the location of frequently used files such as Excel workbooks, Word documents, PDFs, or any other file type you’ve linked.

    This entire process takes only a few mouse clicks, something you’re likely to do many times throughout the day. You can also import files in batches, and each selection will be added automatically to the directory-list table, building your library of linked documents.

    The Data Sheet Form Design.

    The Form has a simple design, as shown in the image above. The following are the main elements of the design.

    1. A Table: DirectoryList with two Fields: 1. FileLinks with data type Hyperlink. 2. Path with a Text data type to store the file’s complete path name.

    2. The Datasheet Form was created in the above Table with the name FilesListing_Sub.

    3. The Main Form Files Listing with the Datasheet Form inserted as a Sub-Form that occupies the major part of the design.

    4. A Command Button (Name: cmdFileDialog) with the Caption Create File Links runs the Common Dialog Control to browse and select files from the Disk and insert them as Hyperlinks in the FileLinks Field of the Table.

    5. The Field Path will be updated with the location address of the selected files.

    6. The Unbound Text Box below will show the Current Project Path as the default location when the File Dialog is open.

    7. The Command Button with the name cmdDelAll, and the Caption Delete All Links,  clicks to delete all file links from the tables.

    8. The Command Button with the name cmdDelLink and the Caption Delete One Link, clicks to delete the selected hyperlink item from the List.  You can manually delete one or more Links, select them by holding the Shift key down and clicking on the left border of items next to each other, and press the DELETE Key.

    9. Command Button with the Caption Delete File on Disk and the name cmdDelFile deletes the selected Link, followed by physically deleting the file on disk.  So be careful with this option. Only one File can be deleted at a time.  Use this option with caution; once the file is deleted from the disk, it cannot be reversed.  Click on the left border of a link to select it, and click on the Delete File on Disk.

Managing the Files List

The Files' List is created as Hyperlinks in the target table named DirectoryList. Each record in this table consists of the file’s display name and its corresponding full path stored as a valid hyperlink reference.

New links can be added to the list at any time, and the incoming links are automatically appended to the existing records without overwriting previous entries. Manual data entry or direct editing of hyperlinks through the Form is not allowed, ensuring that the hyperlink structure remains intact.

If you wish to make experimental changes, open the DirectoryList table directly in Datasheet View and modify it there. However, this is not recommended, since any accidental changes to the Hyperlink Value Segments (the visible text, the actual address, or the optional sub-address) may break the link or cause it to open incorrectly.

If you would like to know more about the Hyperlink value Segments (four segments) and what they do, go to the link Open Forms with Hyperlinks in ListBox.

Download the sample database from the bottom of this page and try it out before you design one of your own to understand how it works.

You can easily implement this in your various Projects by simply importing the Forms and the Table into your Projects if required. The demo database is an Access 2007 Version file.

The Main Form Class Module Code

The VBA Code, which runs behind the Main Form Files Listing, is listed below for info.

Option Compare Database
Option Explicit
Dim strpath As String

Private Sub cmdClose_Click()
DoCmd.Close acForm, Me.Name
End Sub

Private Sub cmdDelFile_Click()
On Error GoTo cmdDelFile_Click_Err
Dim db As DAO.Database, rst As DAO.Recordset
Dim strFile As String

strFile = Me.DirectoryList.Form!Path
Set db = CurrentDb
Set rst = db.OpenRecordset("DirectoryList", dbOpenDynaset)
rst.FindFirst "Path = '" & strFile & "'"
If Not rst.NoMatch Then
If MsgBox("File: " & strFile & vbCr & "DELETE from Disk?", _
vbQuestion + vbYesNo, "cmdDelFile_Click") = vbYes Then
   If MsgBox("Are you sure you want to Delete" & vbCr _
   & rst!Path & " File from DISK?", vbCritical + vbYesNo, "cmdDelFile_Click()") = vbNo Then
    GoTo cmdDelFile_Click_Exit
   End If
    rst.Delete
    rst.Requery
    Me.DirectoryList.Form.Requery
    If Len(Dir(strFile)) > 0 Then
    Kill strFile
    MsgBox "File: " & strFile & " Deleted."
    Else
      MsgBox "File: " & strFile & vbCr & "Not Found on Disk!"
    End If
End If
Else
    MsgBox "File: " & strFile & " Not Found!!"
End If

cmdDelFile_Click_Exit:
rst.Close
Set rst = Nothing
Set db = Nothing
Exit Sub

cmdDelFile_Click_Err:
MsgBox Err & " : " & Err.Description, , "cmdDelFile_Click()"
Resume cmdDelFile_Click_Exit
End Sub

Private Sub cmdHelp_Click()
DoCmd.OpenForm "Help", acNormal
End Sub

Private Sub Form_Load()
'strpath = CurrentProject.Path & "\*.*"
On Error GoTo Form_Load_Err
GetProperty
strpath = Me!PathName

Form_Load_Exit:
Exit Sub

Form_Load_Err:
MsgBox Err & " : " & Err.Description, , "Form_Load()"
Resume Form_Load_Exit
End Sub

Private Sub cmdDelLink_Click()
On Error GoTo cmdDelLink_Click_Err
Dim db As DAO.Database, rst As DAO.Recordset
Dim strFile As String

strFile = Me.DirectoryList.Form!Path
Set db = CurrentDb
Set rst = db.OpenRecordset("DirectoryList", dbOpenDynaset)
rst.FindFirst "Path = '" & strFile & "'"
If Not rst.NoMatch Then
If MsgBox("Link: " & strFile & vbCr & "DELETE from above List?", _
vbQuestion + vbYesNo, "cmddelLink_Click()") = vbYes Then
    rst.Delete
    rst.Requery
    Me.DirectoryList.Form.Requery
    MsgBox "File Link: " & strFile & " Deleted."
End If
Else
    MsgBox "Link: " & strFile & " Not Found!!"
End If
rst.Close
Set rst = Nothing
Set db = Nothing

cmdDelLink_Click_Exit:
Exit Sub

cmdDelLink_Click_Err:
MsgBox Err & " : " & Err.Description, , "cmdDelLink_Click()"
Resume cmdDelLink_Click_Exit

End Sub

Private Sub cmdFileDialog_Click()
On Error GoTo cmdFileDialog_Click_Err
'Requires reference to Microsoft Office 12.0 Object Library.
Dim db As DAO.Database, rst As DAO.Recordset
   Dim fDialog As Office.FileDialog
   Dim varFile As Variant
Dim strfiles As String
   'Clear listbox contents.
   'Me.FileList.RowSource = ""

   'Set up the File Dialog.
   Set fDialog = Application.FileDialog(msoFileDialogFilePicker)
   With fDialog
      'Allow user to make multiple selections in dialog box.
      .AllowMultiSelect = True
      .InitialFileName = strpath
            
      'Set the title of the dialog box.
      .Title = "Please select one or more files"

      'Clear out the current filters, and add our own.
      .Filters.Clear
      .Filters.Add "All Files", "*.*"
      .Filters.Add "Access Databases", "*.mdb; *.accdb"
      .Filters.Add "Access Projects", "*.adp"
      .Filters.Add "Excel WorkBooks", "*.xlsx; *.xls; *.xml"
      .Filters.Add "Word Documents", "*.docx; *.doc"

      'Show the dialog box. If the .Show method returns True, the
      'user picked at least one file. If the .Show method returns
      'False, the user clicked Cancel.
      If .Show = True Then
    'i = .FoundFiles.Count
    'MsgBox "File found = " & .FoundFiles.Count
    'DoCmd.SetWarnings False
    'DoCmd.RunSQL "DELETE DirectoryList.* FROM DirectoryList;"
    'DoCmd.SetWarnings True
    Set db = CurrentDb
    Set rst = db.OpenRecordset("DirectoryList", dbOpenDynaset)
    'For i = 1 To .FoundFiles.Count
        For Each varFile In .SelectedItems
        rst.AddNew
        strfiles = Mid(varFile, InStrRev(varFile, "\") + 1)
        strfiles = strfiles & "#" & varFile & "##Click"
        rst![FileLinks] = strfiles
        rst![Path] = varFile
        rst.Update
    Next
Me.DirectoryList.Form.Requery
         'Loop through each file selected and add it to the list box.
         'For Each varFile In .SelectedItems
            'Me.FileList.AddItem varFile
         'Next
      Else
         MsgBox "You clicked Cancel in the file dialog box."
      End If
   End With

cmdFileDialog_Click_Exit:
Exit Sub

cmdFileDialog_Click_Err:
MsgBox Err & " : " & Err.Description, , "cmdFileDialog_Click()"
Resume cmdFileDialog_Click_Exit
End Sub

Private Sub Form_Unload(Cancel As Integer)
If Len(strpath) = 0 Then
  strpath = "C:\My Documents\*.*"
End If
SetProperty
End Sub

Private Sub PathName_AfterUpdate()
'On Error GoTo PathName_AfterUpdate_Err
Dim str_path As String, i As Long
Dim test As String

    Me.Refresh
    str_path = Me!PathName
    i = InStrRev(str_path, "\")
    str_path = Left(str_path, i) & "*.*"
    strpath = str_path
    
    test = Dir(strpath)
    If Len(test) = 0 Then
        MsgBox "Invalid PathName: " & strpath
        strpath = CurrentProject.Path & "\*.*"
        Me.PathName = str_path
        Me.Refresh
        Exit Sub
    End If
    Me.PathName = strpath
    Me.Refresh
    
PathName_AfterUpdate_Exit:
Exit Sub

PathName_AfterUpdate_Err:
MsgBox Err & " : " & Err.Description, , "PathName_AfterUpdate()"
Resume PathName_AfterUpdate_Exit
End Sub

Private Function GetProperty() As String
On Error GoTo GetProperty_Err
Dim doc As DAO.Document
Dim db As DAO.Database
Dim prp As DAO.Property
Dim strLoc As String

Set db = CurrentDb
Set doc = db.Containers("Forms").Documents("FilesListing")
strLoc = doc.Properties("defaultpath").Value
If Len(strLoc) = 0 Then
   strLoc = CurrentProject.Path & "\*.*"
End If

strpath = strLoc
Me!PathName = strpath
Me.Refresh

GetProperty_Exit:
Exit Function

GetProperty_Err:
MsgBox Err & " : " & Err.Description, , "GetProperty()"
Resume GetProperty_Exit
End Function


Private Function SetProperty() As String
On Error GoTo SetProperty_Err
Dim doc As DAO.Document
Dim db As DAO.Database
Dim prp As DAO.Property
Dim strLoc As String

Set db = CurrentDb
Set doc = db.Containers("Forms").Documents("FilesListing")
strLoc = Me!PathName
If Len(strLoc) = 0 Then
    strLoc = CurrentProject.Path & "\*.*"
End If
doc.Properties("defaultpath").Value = strLoc

SetProperty_Exit:
Exit Function

SetProperty_Err:
MsgBox Err & " : " & Err.Description, , "SetProperty()"
Resume SetProperty_Exit
End Function

Download Demo Database

Download Demo DirListing2K1.zip

Share:

PRESENTATION: ACCESS USER GROUPS (EUROPE)

Translate

PageRank

Post Feed


Search

Popular Posts

Blog Archive

Powered by Blogger.

Labels

Forms Functions How Tos MS-Access Security Reports msaccess forms Animations msaccess animation Utilities msaccess controls Access and Internet MS-Access Scurity MS-Access and Internet Class Module External Links Queries Array msaccess reports Accesstips WithEvents msaccess tips Downloads Objects Menus and Toolbars Collection Object MsaccessLinks Process Controls Art Work Property msaccess How Tos Combo Boxes Dictionary Object ListView Control Query VBA msaccessQuery Calculation Event Graph Charts ImageList Control List Boxes TreeView Control Command Buttons Controls Data Emails and Alerts Form Custom Functions Custom Wizards DOS Commands Data Type Key Object Reference ms-access functions msaccess functions msaccess graphs msaccess reporttricks Command Button Report msaccess menus msaccessprocess security advanced Access Security Add Auto-Number Field Type Form Instances ImageList Item Macros Menus Nodes RaiseEvent Recordset Top Values Variables Wrapper Classes msaccess email progressmeter Access2007 Copy Excel Export Expression Fields Join Methods Microsoft Numbering System Records Security Split SubForm Table Tables Time Difference Utility WScript Workgroup database function msaccess wizards tutorial Access Emails and Alerts Access Fields Access How Tos Access Mail Merge Access2003 Accounting Year Action Animation Attachment Binary Numbers Bookmarks Budgeting ChDir Color Palette Common Controls Conditional Formatting Data Filtering Database Records Defining Pages Desktop Shortcuts Diagram Disk Dynamic Lookup Error Handler External Filter Formatting Groups Hexadecimal Numbers Import Labels List Logo Macro Mail Merge Main Form Memo Message Box Monitoring Octal Numbers Operating System Paste Primary-Key Product Rank Reading Remove Rich Text Sequence SetFocus Summary Tab-Page Union Query User Users Water-Mark Word automatically commands hyperlinks iSeries Date iif ms-access msaccess msaccess alerts pdf files reference restore switch text toolbar updating upload vba code