Learn Microsoft Access Advanced Programming Techniques, Tips and Tricks.

Progress Meter

Introduction.

When we process a large volume of data for MS-Access Reports it may take a few minutes to several minutes to complete, depending on the transaction volume involved. The transactions are organized and processed through Select Queries, and Action Queries, sequencing the process through Macros and VBA routines to arrive at the final Report Data.  If you have Action Queries that pull data from Select, Crosstab Queries, and if a large volume of transactions is involved, it may take longer than the Normal Queries to filter for output.

In all these situations it will be difficult for the user to know how long the whole process will take to complete the task. After running the process a few times the user may get a rough idea as to how long it will take to finish. 

Normally at the beginning of a lengthy process, the Mouse Pointer can be turned on into an Hourglass shape (Docmd.Hourglass True) indicating that the machine is engaged, and can be turned it off at the end of the process. But, this method will not give an exact indication as to when the process will be over.  

If it takes more than the usual running time, depending on other factors, like an increase in the volume of transactions or due to busy network traffic and so on, it is difficult to determine whether the process is really running or it is a machine hang up issue.

The Quick Solution

When we run several Action Queries in a chain from within a Macro, MS-Access displays a Progress Meter for a brief moment for each Query on the Status Bar. If the Status Bar is not visible you can turn it on. Select Options from the Tools menu, and select View Tab on the displayed Dialog Control. Put a check-mark in the Status Bar option, under Show Options Group. But it will not give an overall time indicator for the full process.

A Better Approach.

We will make use of the Progress Meter for our data processing tasks more effectively and will look into more than one method. The users of our Application can relax during the whole process and take little time off to flip through the Weekly Magazine with an occasional glance at the Progress Meter.

  1. Displaying the Progress Meter on the Status Bar
  2. Displaying the Progress Meter on a Form
  3. Usage of a transaction countdown method.

Usage of Progress Meter on the Status Bar.

We will use the Order Details Table from the Northwind.mdb sample database for our example and write a VB Routine to calculate the Extended Price on each entry in this Table. If you have not already imported this Table for our earlier examples you may do it now. If you don't know the exact location of this file on your machine, please visit the Page Saving Data on Forms not in Table for references.

  1. Import the Order Details Table from Northwind.mdb sample Database.
  2. Open the Order Details Table in Design View and add a new field with the name ExtendedPrice (Field Type: Number, Field Size: Double) at the end of the existing fields. We will write a program to calculate the extended price of each record and update this field.
  3. Design a simple form similar to the one shown below with a Command Button on it. We will modify this Form for our next example also.
  4. Click on the Command Button and display the Property Sheet (View -> Properties).
  5. On the On Click Property type =ProcessOrders() to run the program, which we are going to write now. Do not forget the equal sign in =ProcessOrders(), otherwise, MS-Access will take it as a Macro name.
  6. Close the form and save it with the name ProgressMeter.

    Usage of SysCmd().

  7. Copy and Paste the following Code into a Global VB Module of your Project and save it.
    Public Function ProcessOrders()
    Dim db As Database, rst As Recordset
    Dim TotalRecords As Long, xtimer As Date
    Dim ExtendedValue As Double, Quantity As Integer
    Dim Discount As Double, x As Variant, UnitRate As Double
    
    On Error GoTo ProcessOrders_Err
    
    DoCmd.Hourglass True
    
    Set db = CurrentDb
    Set rst = db.OpenRecordset("Order Details", dbOpenDynaset)
    rst.MoveLast
    TotalRecords = rst.RecordCount
    
    rst.MoveFirst
    Do While Not rst.EOF
      With rst
        Quantity = ![Quantity]
        UnitRate = ![UnitPrice]
        Discount = ![Discount]
        ExtendedValue = Quantity * (UnitRate * (1 - Discount))
    
        .Edit
        ![ExtendedPrice] = ExtendedValue
        .Update
    
        If .AbsolutePosition + 1 = 1 Then
           x = SysCmd(acSysCmdInitMeter, "process:", TotalRecords)
        Else
          'a delay loop to slow down the program       
          'to view the Progress Meter in action.      
          'you may remove it.      
    '=================================================
          xtimer = Timer
          Do While Timer < xtimer + 0.02
            Doevents
          Loop
    '=================================================
    
          x = SysCmd(acSysCmdUpdateMeter, .AbsolutePosition + 1)
        End If
    
       .MoveNext
      End with
    Loop
    rst.Close
    x = SysCmd(acSysCmdRemoveMeter)
    DoCmd.Hourglass False
    
    MsgBox "Process completed.", , "ProcessOrders()"
    
    Set rst = Nothing
    Set db = Nothing
    
    ProcessOrders_Exit:
    Exit Function
    
    ProcessOrders_Err:
    MsgBox Err.Description, , "ProcessOrders()"
    Resume ProcessOrders_Exit
    
    End Function
  8. Open the ProgressMeter Form in normal view and click on the Command Button. You will see the Progress Meter slowly advancing and when it reaches the end of the bar a message will appear announcing that the work is complete.

We have used MS-Access's built-in Function SysCmd() to update the Progress Meter on the Status Bar. When the Function is first called, the Maximum Number of Records in the File is passed as the third parameter to the function to initialize the Progress Meter. Subsequent calls are made with the current record number to update the Meter with the current status. MS-Access calculates a percentage of the current number of records processed based on the Total Records that we have passed to the InitMeter step and updates the Progress Meter. The blue-colored indicator on the Progress Meter may advance one step, only after processing several records depending on the total number of records in the file.

A delay loop is built into the Code to slow down the program and view the Progress Meter in action. You may remove these lines when using them in your Project.

Need a Better Method

We cannot use this method when we sequence our process steps in Macros involving Queries. Because, when each Action Query is run MS-Access uses the Status Bar to display the progress of each and every query separately overwriting our overall process time meter. We have to devise a method of our own to do this.

Next, we will see the usage of a Progress Meter on a Form, for the Data Processing steps sequenced through Macro.

Download


Download Access2007 Version



Download Access2003 Version

Share:

Keyboard Shortcuts

Introduction.

Keyboard Shortcuts are very useful, if practiced and memorized, for frequently used actions without shifting back and forth between mouse and keyboard. Microsoft Access has an extensive list of Keyboard Shortcuts to make our work much easier. You can enter the search term Keyboard Shortcuts on the Help Menu to get a category-wise list. I have selected some of them and given them at the end of this post for reference.

If you look carefully at the MS-Access Menu Options you can find one letter in each Menu Item is underlined indicating that it is a Keyboard Shortcut Code.

For example, the letter E in the Edit menu is underlined, indicating that you can open the Edit Menu using ALT+E Keyboard Shortcut. Most of the Options within the Edit Menu also have keyboard shortcut Codes on the right side of each one. These are all predefined keyboard shortcuts in the system.

Defining Custom Shortcuts

When we design Forms we can define our own custom Keyboard Shorts (Access Keys) on the Form Controls in a similar way with the help of a & symbol. If you insert a & symbol on the left side of a character in the Caption of the Command Button (or in the Caption of a Label) you can use ALT+character to make the Command Button act as if it is being clicked and runs the action programmed into that Button.

For example, if you have a Command Button on a Form with the Caption Export you can write the Caption as &Export; so that ALT+E Keyboard Shortcut can be used to run the Export action. When we define keyboard shortcuts this way we should see that does not end up with the same built-in Shortcuts.

 Here, we already have a Built-in Keyboard Short &Edit, which uses the ALT+E combination. We can insert the & symbol on the left side of any letter within the word Export (like Ex&port for ALT+P) to avoid conflict with the built-in codes.

There are other methods to define Keyboard Shortcuts. You can put all your Custom Keyboard Shortcuts in a Macro for specific actions, like Print Previewing/Printing Report, for opening a Particular Form in Design View or Normal View, Run a Macro to Process Report Data, etc. You must name the Macro as Autokeys. An image of the Example Macro is given below.

The first line Action OpenReport runs when the CTRL+O keys are used, CTRL+K runs another Macro.

If you assign an action to a key combination that is already being used by MS-Access (for example, CTRL+C is the key combination for Copy), the action you assign this key combination replaces the Access key assignment.

AutoKeys

A list of key combinations that you can use in your Autokeys Macro is given below.

Key Codes for Autokey Macro
Key Code Key Press
^A or ^4 CTRL+A or CTRL+4
{F1} F1
^{F1} CTRL+F1
+{F1} SHIFT+F1
{INSERT} INS
^{INSERT} CTRL+INS
+{INSERT} SHIFT+INS
{DELETE} or {DEL} DEL
^{DELETE} or ^{DEL} CTRL+DEL
+{DELETE} or +{DEL} SHIFT+DEL

A macro with the name Autoexec runs automatically when you open a database.

General Purpose Keyboard Shortcuts

A list of useful general-purpose Keyboard Shortcuts is given below for your reference.

Seq Key Strokes Action
SAVING AND PRINTING
1. CTRL+S or SHIFT+F12 or ALT+SHIFT+F2 To save a Database Object
2. F12 or ALT+F2 To open the Save As... dialog box
3. CTRL+P To Print the Current or Selected Object
FINDING REPLACING
4. CTRL+F To open the Find tab in the Find and Replace dialog box (Datasheet view and Form view only
5. CTRL+H To open the Replace tab in the Find and Replace dialog box (Datasheet view and Form view only)
6. SHIFT+F4 To find the next occurrence of the text specified in the Find and Replace dialog box when the dialog box is closed (Datasheet view and Form view only)
WORKING IN DESIGN VIEW
7. F2 To switch between Edit mode (with insertion point displayed) and Navigation mode
8. F4 To switch to the property sheet (Design view in forms and reports in databases and Access projects)
9. F5 To switch to Form view from the form Design view
10. F6 To switch between the upper and lower portions of a window (Design view of tables, macros, and queries and the Advanced Filter/Sort window only)
11. SHIFT+F7 To switch from the Visual Basic Editor to form or report Design view
12. ALT+V+P To open the property sheet for a selected object
Editing Controls in Form and Report Design View
13. CTRL+C To copy the selected control to the Clipboard
14. CTRL+X To cut the selected control and copy it to the Clipboard
15. CTRL+V To paste the contents of the Clipboard in the upper-left corner of the selected section
16. CTRL+RIGHT ARROW To move the selected control to the right
17. CTRL+LEFT ARROW To move the selected control to the left
18. CTRL+DOWN ARROW To move the selected control down
19. SHIFT+DOWN ARROW To increase the height of the selected control
20. SHIFT+RIGHT ARROW To increase the width of the selected control
21. SHIFT+UP ARROW To reduce the height of the selected control
22. SHIFT+LEFT ARROW To reduce the width of the selected control
WINDOW OPERATIONS
23. F11 To bring the Database window to the front
24. CTRL+F6 To cycle between open windows
25. ENTER To restore the selected minimized window when all windows are minimized
26. CTRL+F8 To turn on Resize mode for the active window when it's not maximized; press the arrow keys to resize the window
27. ALT+SPACEBAR To display the Control menu
28. SHIFT+F10 To display the shortcut menu
29. CTRL+W or CTRL+F4 To close the active window
30. ALT+F11 To switch between the Visual Basic Editor and the previous active window
MISCELLANEOUS
31. F7 To check to spell
32. SHIFT+F2 To open the Zoom box to conveniently enter expressions and other text in small input areas
33. ALT+ENTER To display a property sheet in the Design view
34. ALT+F4 To quit Microsoft Access, close a dialog box, or close a property sheet
35. CTRL+F2 To invoke a Builder

Share:

Find or Filter Data on Form

Introduction

When I started learning Microsoft Access in 1996 the first challenge that I faced was how to find a particular record on the Data Editing Screen or Filter a group of records on some condition.

I was asked to develop a System for the Vehicles Division of our Company, for tracking pending Orders and Receipts of Heavy Equipment and Vehicles. If I am the one who is going to use the System, then somehow I could manage to find the information that I want to work with and nobody will know how much time I spent doing that. But it is going to be used by someone else and it is my job to make it as user-friendly as possible. Even though I have good knowledge of BASIC Language at that time, knew nothing about Access Basic (MS-Access Ver.2 language, a primitive form of Visual Basic).

I struggled with the problem for a while and finally decided to have a look in the Northwind.mdb sample database for clues. There it was, on the Customer Phone List Form, the technique that I struggled with for so long. Within an Option Group Control, 27 Buttons with Labels A-Z, All to filter Records of Company Name starting with the respective letter on the Button or to remove the filter using the All labeled button. The Options Group is linked to a Macro. When any of the buttons on the option group is clicked, the Company Names starting with that letter are filtered from the Customer List.

There were no second thoughts on this and I straight away transplanted this method to my first MS-Access Project. It was developed without touching a single line of Access Basic Code, all automated procedures are by macros only.

We will look into the Finding/Filtering records using three different methods on the same Form. You can use any one of the three methods or all of them in your Project. We will use the Products Table from the Northwind.mdb sample Database.

Get Sample Table and Design a Form

  1. Import the Products Table from the Northwind.mdb Database. Visit the Page Saving Data on Forms not in Table to find the location reference of the Northwind.mdb database, if you are not sure where to find it.

  2. Click on the Table and select Form from the Insert menu and select Autoform: Columnar from the displayed list, click OK to create the Form and save it with the suggested name: Products.

  3. Display the Form Header/Footer Sections, if not already visible. Select Form Header/Footer from View Menu.

  4. Create a Label on the Header Section of the Form and type Products Lists as Caption. Click on the Label and change the font size to 20 or more, to your liking, and make it Bold using the Format Toolbar above.

    NB: If you would like to create a fancy 3D Style Heading then visit the Page: Shadow 3D Heading Style and follow the procedure explained there.

  5. Create a Command Button at the Footer Section of the Form. Display the Property Sheet of the Button (Alt+Enter or select Properties from View Menu). Change the Property Values as shown:

    • Name = cmdExit

    • Caption = Exit

  6. Design a Text Box and four Command Buttons on the Form, as shown in the shaded area of the Form. Change the property values of the Text Box and Buttons as given below:

  7. Click on the Text Box, Display the Property Sheet, and change the property values:

    • Name = xFind

    • Back Color = 0

    • Text Box child-Label Caption = Find / Filter Product Name

  8. Click on the first button, Display the Property Sheet, and change the property Values.

    • Name = FindPID

    • Caption = << Product ID

    • Fore Color = 128

  9. Click on the second button, Display the Property Sheet, and change the property Values.

    • Name = FindFirstLetter

    • Caption = << First Letter

    • Fore Color = 128

  10. Click on the third Button, Display the Property Sheet, and change the property Values.

    • Name = PatternMatch

    • Caption = << Pattern Match

    • Fore Color = 128

  11. Click on the fourth Button, Display the Property Sheet, and change the property Values.

    • Name = cmdReset

    • Caption = Reset Filter

  12. Display the Visual Basic Module of the form, select Tools > Macros > Visual Basic Editor when the Products Form is still in Design View.

  13. VBA Code of Form Class Module

  14. Copy and paste the following Code into the VB Module of the Form and save the Form:

Private Sub cmdExit_Click()
DoCmd.Close
End Sub

Private Sub cmdReset_Click()
'Remove Filter effect
'Clear Text Box

Me!xFind = Null
Me.FilterOn = False
End Sub

Private Sub FindPID_Click()
'Find Record matching Product ID
Dim m_find, rst As Recordset

m_find = Me![xFind]
If IsNull(m_find) Then
   Me.FilterOn = False
   Exit Sub
End If

If Val(m_find) = 0 Then
  MsgBox "Give Product ID Number..!"
   Exit Sub
End If

If Val(m_find) > 0 Then
   Set rst = Me.RecordsetClone
   rst.FindFirst "ProductID = " & m_find
   If Not rst.NoMatch Then
      Me.Bookmark = rst.Bookmark
   End If
   rst.Close
End If

End Sub

Private Sub FindfirstLetter_Click()
'Filter Names matching First character
Dim xfirstletter

xfirstletter = Me![xFind]
If IsNull(xfirstletter) Then
  Me.FilterOn = False
  Exit Sub
End If
If Val(xfirstletter) > 0 Then
   Exit Sub
End If

xfirstletter = Left(xfirstletter, 1)
Me.FilterOn = False
Me.Filter = "Products.ProductName Like '" & xfirstletter & "*'"
Me.FilterOn = True

End Sub

Private Sub PatternMatch_Click()
'Filter Names matching the group of characters
'anywhere within the Name
Dim xpatternmatch

xpatternmatch = Me![xFind]
If IsNull(xpatternmatch) Then
  Me.FilterOn = False
  Exit Sub
End If

Me.FilterOn = False
Me.Filter = "Products.ProductName Like '*" & xpatternmatch & "*'"
Me.FilterOn = True
End Sub

How it Works.

  1. Usage of << Product ID Button.

    • Click the Button with a number less than or equal to the Product Code range of values in the Text Box.

    • If clicked with Text Value it will ask for Product ID Number.

    • If clicked when the TextBox is empty, it is the same as clicking Filter Reset Button.

  2. Usage of << First Letter Button.

    • Click the Button with any Alphabet A to Z or a to z in the Text Box.

    • If more than one character is entered only the first character will be taken.

    • If a Numeric Value is entered the filter action will be ignored.

    • If clicked when the TextBox is empty, it is the same as clicking the Filter Reset Button.

  3. Usage of << Pattern Match Button.

    • Click the Button with a group of characters that match anywhere within the Product Name.

    • If clicked when the text box is empty, it is the same as clicking the Filter Reset Button.

  4. Usage of Filter Reset Button.

    • Resets the earlier applied Filter action.

    • Empties the Text Box Control.

Share:

Who is Online

Introduction.

We already know that we can install Access Database on a Local Area Network (LAN) and several Users can work on it at the same time. But it is difficult to know how many users are actually online with the Application at a given time.

Similarly, when there are several MS-Access Databases on a Network under a centrally controlled Security Workgroup it will be interesting to know which users are currently working on the MS-Access Applications on the Network.

You don't need any complicated programs to find this out. When someone opens a Database, say NorthWind.mdb, MS-Access opens a Lock-File with the same name of the Database with file extension ldb (Northwind.ldb) in the same folder of the Database. You can open this file with Notepad or any other Text Editor and view the contents.

This file contains the Workstation Ids and MS-Access User IDs of all the active users of the Database. The lock file will be deleted by MS-Access when all the Users close the database. In other words, if a Lock File is not active then nobody is currently using the database.

We can implement MS-Access Security of several Databases with a common Workgroup File in a Network holding Workgroup IDs, User IDs, and User Passwords. In such situations, there will be a common Workgroup File, (a Database with MDW extension), accessible to all the Users in a Network. When someone Log-in to the Workgroup to open a database, a lock file with the ldb extension will open up with the same name as the Workgroup file. This file will contain the Workstation IDs and User IDs of all the Users currently active across different databases.

We will design a Form and write Programs to open the Lock-File of a Database or Workgroup File and display the List of Workstation IDs and User IDs currently active. In addition to that, we will try to send messages through the Network to the selected Users from this list.

Designing a WhoIsOnline Form

  1. Design a Form similar to the one shown below and change the Properties of the Controls as explained. Smaller controls are TextBoxes and the big Control under the label Users Online is a List Box.

  2. Click on the Text Box below the label: Workgroup or Database File Path and display the property sheet. Change the value of the Name Property to FPath.

  3. Display the Property Sheet of the List Box and change the value of the following properties as given below:

    • Name = UsrList
    • Row Source Type = Value List
    • Column Count = 2
    • Column Heads = No
    • Column Width = 1.25";1.25"
    • Bound Column = 1
    • Multi Select = simple
  4. Display the property sheet of the Text Box above the Send Message Button and change the value of the Name Property to msgtxt.

  5. Display the Property Sheet of the Button with the caption symbol < and change the value of the Name Property to cmdUpdate.

  6. Display the Property Sheet of the Button with the Caption Send Message and change the value of the Name property to cmdNS.

  7. Save the Form with the name; whois online.

    NB: We are referencing all the above Property Values in Programs and it is important that you change the Values of respective controls as explained above.

    Copy and Paste the following code into the VBA Module (Select Tools > Macro > Visual Basic Editor to display the VBA Module) of the whois online Form, Save and Close the Form.

Form Class Module VBA Code

Private Sub cmdNS_Click()
'-------------------------------------------------------
'Author: a.p.r. pillai
'Date  : 01/12/2007
'-------------------------------------------------------
Dim ctl As ListBox, msg As String, usrs As String
Dim i As Integer, pcs() As String, xmsg As String
Dim ic As Integer, j As Integer, lc As Integer

On Error GoTo cmdNS_Click_Err

xmsg = Nz(Me.msgtxt, "")

If Len(xmsg) = 0 Then
   MsgBox "Message Control is Empty.", , "cmdNS_Click()"
   Exit Sub
End If

Set ctl = Me.UsrList
lc = ctl.listcount
ic = ctl.ItemsSelected.Count

If ic > 0 Then
ReDim pcs(1 To ic, 1 To 2)
i = 0
For j = 0 To lc - 1
If ctl.Selected(j) Then
    i = i + 1
    pcs(i, 1) = ctl.Column(0, j)
    pcs(i, 2) = ctl.Column(1, j)
End If
Next

usrs = ""
For j = 1 To i
msg = "NET SEND " & pcs(j, 1) & " User: " & pcs(j, 2) & " " & xmsg
  Call Shell(msg)
  If Len(usrs) = 0 Then
     usrs = j & ". WorkStationID: " & pcs(j, 1) & "  UserID: " & pcs(j, 2)
  Else
     usrs = usrs & vbCr & j & ". WorkStationID: " & pcs(j, 1) & "  UserID: " & pcs(j,2)
  End If
Next
  MsgBox "Messages Sent to:" & vbCr & vbCr & usrs & vbCr & vbCr & "successfully.", , "cmdNS_Click()"
Else
  MsgBox "Select one or more Users in list and try again.", , "cmdNS_Click()"
End If

cmdNS_Click_Exit:
Exit Sub

cmdNS_Click_Err:
MsgBox Err.Description, , "cmdNS_Click()"
Resume cmdNS_Click_Exit
End Sub

Private Sub cmdUpdate_Click()
    Me.UsrList.SetFocus
    Me.cmdUpdate.Enabled = False
   WhoisOnline Me.FPath
    Me.cmdUpdate.Enabled = True
End Sub

The Main Program

Copy and Paste the following VBA Code into a Global Module in your Project and save:

Public Function WhoisOnline(ByVal strPathName)
'-------------------------------------------------------
'Author : a.p.r. pillai
'Date   : 01/12/2007
'-------------------------------------------------------
Dim strldb() As String, j As Integer, strpath As String
Dim str As String, intlen As Integer, t As Date
Dim pos As Integer, xsize As Integer, l As Integer
Dim FRM As Form, ctl As ListBox, qt As String
Dim x As String

Const strlen As Integer = 62

On Error Resume Next

qt = Chr$(34)

strpath = Trim(Nz(strPathName, ""))

If Len(strpath) = 0 Then
  MsgBox "File Path is Empty.", , "WhoisOnline()"
  Exit Function
End If

str = Right(strpath, 4)
l = InStr(1, ".mdb.mdw.ldb", str)
Select Case l
    Case 0
      strpath = strpath & ".ldb"
    Case 1, 5
      strpath = Left(strpath, Len(strpath) - 4) & ".ldb"
    Case 9       'it is .ldb no action
End Select

Set FRM = Forms("WhoisOnline")
Set ctl = FRM.Controls("UsrList")

Open "c:\x.bat" For Output As #1
Print #1, "@Echo off"
Print #1, "copy " & strpath & " c:\xx.txt"
Close #1

Call Shell("c:\x.bat", vbHide)

x = Dir("c:\xx.txt")t = Timer
Do While Len(x) = 0 And Timer < (t + 2)
   x = Dir("c:\xx.txt")
Loop

t = Timer
Do While Timer < (t + 2)   'do nothingLoop

Open "c:\xx.txt" For Input As #1
If Err > 0 Then
  'Lock file copying was not successfull
  MsgBox "Database is idle.", , "WhoisOnline()"
  Exit Function
End If
Input #1, str
Close #1

intlen = Int(Len(str) / strlen) + 1
ReDim strldb(1 To intlen, 1 To 2) As String
xsize = strlen / 2

For j = 1 To intlen
  pos = IIf(j = 1, 1, (j - 1) * strlen + 1)
  strldb(j, 1) = Trim(Mid(str, pos, xsize))
  pos = pos + strlen / 2
  strldb(j, 2) = Trim(Mid(str, pos, xsize))
Next

str = ""
For j = 1 To intlen
  If Len(str) = 0 Then
    str = qt & Trim(strldb(j, 1)) & qt & ";" & qt & Trim(strldb(j, 2)) & qt
  Else
    str = str & ";" & qt & Trim(strldb(j, 1)) & qt & ";" & qt & Trim(strldb(j, 2)) & qt
  End If
Next
ctl.RowSource = strctl.Requery
Kill "c:\x.bat"
Kill "c:\xx.txt"

End Function

NOTE: The above VBA Code was written for Windows XP and the NET SEND message Command is used for sending messages to a Workstation. Windows 10/08/7 uses the MSG Command. Type C:\MSG /? In the Command Prompt for full Parameter List and Options.

In the above program, we are creating a DOS Batch File (c:\x.bat) and running it, to make a copy of the Lock-File c:\xx.txt as a work file.

The Demo Run

  1. Open the Whois online Form in Normal View. Type the full path of an active database (Tip: give the Path and Name of the Database you are currently working on, if you are not on a Network). If you are on a Network and have a common MS-Access Workgroup File, on which other users are currently connected, then give that File's PathName. No need to give File Name extensions mdb, mdw, or ldb, but if you wish to include you may do so for clarity.

  2. Click on the Button with < symbol.

  3. Select one or two Workstation IDs in the List Box.

  4. Type a message in the Text Box Control above the Send Message Button for the selected Users.

  5. Click on the Send Message Button. The Message Text will pop up on the selected Users' Machines.

NB: If you have selected your own machine name, then the Send Message action will not work.

Download Demo Database


Download Demo Who-is-online.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