Monday, October 31, 2011

New Sample: Query_A2K10_MultiValueFields

By AD Tejpal

    This sample db demonstrates query based approach to bulk appending / updating / make table actions involving multi-value  fields in Access 2010, without resorting to use of recordset or recordset2 objects, thus overcoming a known limitation associated with such fields.

    In this arrangement, an extra field named TempID is provided in the destination table. The append query is executed in two stages. In first stage, primary key values from source table are appended to TempID field in destination table. In 2nd stage, value elements of MVF field get appended, using an inner join between the source and destination tables (PK of source table equals TempID of destination table).

    Three styles are covered as follows:

  •     (a) Bulk appending of selected records (having multi-value fields) from one table to another.
  •     (b) Bulk updating of multi-value field elements (addition or replacement of values) in destination table based upon values held in source table.
  •     (c) Make table action covering multi-value fields based upon selected records in source table.  

Version: Access 2010 accdb file.

You can find the sample here: http://www.rogersaccesslibrary.com/forum/topic575_post593.html#593

Wednesday, October 26, 2011

Referencing Forms, Subforms, and Sub-subforms

 

Introduction

One of the powerful features of Microsoft Access is the ability to reference controls from other controls, in queries, and in code. And yet, while most beginning developers master referencing controls on forms relatively quickly, referencing controls on subforms and sub-subforms causes a lot of confusion. Most of this confusion is due to the way in which controls are named.

First, however, a word about naming conventions. I generally encourage the use of meaningful names for controls on a form. In this case, however, I am using generic names like Form1, Subform1, Subsubform1, subControl1, subsubControl1, Text1, and so forth. Objects that I create and name will have a number at the end (Text1). Form collections or properties (like Forms, Controls, Value, or SetFocus) will not have a number at the end.

 

Syntax

There are three different, yet equally correct, syntaxes. For instance, suppose I want to reference the value of a textbox named Text1 on a form named Form1. All of the following work:

Forms!Form1!Text1.Value
Forms("form1")("Text1").Value
Forms(0)(0).Value

 

Bang Syntax

The Bang (!) syntax is the most commonly used syntax in Access, and is generally recommended in Microsoft documentation and articles. The Bang Syntax uses both bangs (!) and dots(.). Bangs are used to separate levels in the DAO hierarchy and dots serve to separate an object from its properties.

So, in the case of our textbox, "Forms" is the Access collection of forms. "Form1" is the name of the form I'm referencing. And "Text1" is the name of the control (textbox).

Forms!Form1.Controls!Text1.Value

The bangs go between the object hierarchy levels. Form1 is a member of the Forms collection. Text1 is a member of the Controls collection of Form1. The dots separate the objects from their collections or properties: The Controls collection of the Form1 object, and the Value property of the Text1 object.

However, every object has a default property and it just happens that Controls is the default for a form and Value is the default for control objects. Therefore you don't actually have to reference them, so I can do something like this:

Forms!Form1!Text1

But if I wanted to reference the caption of the textbox, I'd have to explicitly name it.

Forms!Form1!Text1.Caption

As a general rule of thumb, Bangs (!) go before objects that you, the developer, name like forms, controls, and such. Dots (.) go before things that Access names, like properties and methods. For more on the difference between Bang and Dot, see my post: Bang Vs. Dot In DAO.

It is worthwhile to note that there are times when Bangs and Dots are interchangeable and at other times, it is not.  For instance, in:

Forms!Form1!Text1
Forms.Form1!Text1

the Bang between "Forms" and "Form1" can be replaced with a Dot.  However, the Bang between "Form1" and "Text1" can not.  Best practice is to use the Bangs and Dots correctly to avoid any problems.

 

Paren Syntax

The Paren Syntax simply surrounds each object with parentheses and the name of the object is surrounded in quote marks without bangs or dots:

Forms("form1")("Text1").value

This syntax is most useful in programming where you want to use a variable in place of the object name:

Dim strControlName as String
Dim strFormName as String
strFormName = "Form1"
strControlName = "Text1"
Forms(strFormName)(strControlName).value = "Hello"

Notice the variables are NOT surrounded by quotes.

 

Index Syntax

The Index Syntax is rarely used. It is most commonly used for programmatically looping through controls on a form. For instance, if I wanted to print out the names of all the controls on a form, I could do something like this:

Dim i As Integer
For i = 0 To Forms(0).Controls.Count – 1
   Debug.Print Forms(0)(i).Name
Next i

I could list the names of all the controls on all open forms like this:

Dim i As Integer
Dim j As Integer
For i = 0 To Forms.Count – 1
   For j = 0 To Forms(i).Controls.Count – 1
      Debug.Print Forms(i).Name & ": " & Forms(i)(j).Name
   Next j
Next i

The reality is, however, that there are better ways to do this by directly accessing the Forms Collection and the Controls Collection. Still, it's useful to know about because it can be used in conjunction with other syntax.

 

Mixing and Matching Syntaxes

The various syntaxes can be mixed and matched. For instance, all of the following work identically:

Forms!Form1!Text1
Forms!Form1("Text1")
Forms!Form1(0)
Forms.Form1!Text1
Forms("Form1")!Text1
Forms!Form1.Controls(0).Value
Forms(0)(0).Value
Forms(0)("Text1").Value
Forms!Form1.Controls!Text1.Value

In general, however, unless you have a good reason for it, it's best to stick with the Bang and Dot syntax.

 

A Word About ME

The ME object is a special construct used in forms and reports. It refers to the form or report which has the Focus. If you are referencing objects from within the form/report, you can substitute Me. or Me!

for Forms!Form1.

Me!Text1

Me.Text1
Me!Text1.value
Me.Text1.value
Me.Controls!Text1
Me(Controls)("Text1").value

It doesn't matter which.

If, however, you are referencing the control from outside the form/report -- say in a query -- then you must use explicitly reference the Forms collection and the Form name. That is: Forms!Form1.

For more on the ME object and using the Bang and the Dot in forms, see my blog post: Bang Vs. Dot in Forms.

To see specific examples of referencing subforms and subsubforms, download my sample: SubformReference.mdb from my website (www.rogersaccesslibrary.com).

Friday, October 21, 2011

Featured Sample: Training Registration Database

By Roger Carlson

This database is a fairly robust application for registering employees for training classes.  In it, you can create Courses, create Students, create Classrooms, schedule Courses to Classrooms, and assign Students to Scheduled Courses.   Your first stop will be the Main Menu, where you will have the following choices:

Schedule Classes

Clicking "Scheduled Classes" from the Main Menu brings you to the Scheduled Classes screen. It gives you a summary of the classes already scheduled.

From there,  select an Application and a Course Name to see a listing of all the scheduled classes.  You can filter the selection further by choosing the Past Classes or Future Classes buttons.  You can also schedule a new class with the New Class button.

To view or edit a particular class, click the GO> button to be sent to the Scheduled Class Entry screen.

The Scheduled Class Entry screen allows you to view, edit, or a class, and assign students to it.  By default, the fields in BLUE are locked to prevent accidental changes.  To unlock these fields, click the Unlock button.

Below the Class Information, you can assign students to the class.  The student fields are NOT editable (even if you unlock the other fields).  The only editable field is the Attended field to indicate the student attended the class. Even though you can't edit the information in the student fields, you can re-size and re-arraign the fields at run-time.

You can print a Class Roster from this screen and also certificates of attendance.  The certificates are bare-bones versions that you will want to modify for your company.

As you enroll students, the screen will track the number of seats taken and the number remaining.  It will allow you to over-book a class, but will give you a warning when you do.

By default, the Scheduled Class Entry screen shows just the records you selected on the Scheduled Classes screen.  Clicking the Show All Records button (bottom) will fill the form with all the classes for that Application.  You can use the Record Selector buttons to scroll between them.

Schedule Students

The Schedule Students screen allows you to enter students and assign classes in one step. 

The screen opens to the New Record all set for you to enter a new student.  If you want to edit a student, you can select one from the drop down box at the top of the screen.  You can also use the scroll buttons at the very bottom of the screen.  When you enter an existing student, the fields turn BLUE, which indicates they are locked.  This is to prevent accidental changes.  Click the Edit Record button to unlock the fields.

You can also assign classes to students in this form.  Just select the class from the drop down list.  The particulars of the class will appear below in the blue fields.  Thes cannot be edited in this form.  To do so, you must go to the Scheduled Classes screen.

Reports

The Reports screen allows you to run various reports.  Each report appears as an item in a listbox.  Select the item and click "Open".

There are two types of reports: 1) Simple Reports and 2) Parameter Reports

Simple reports show the same information all the time.  The "All Courses" report is an example.  It displays all of the current courses offered.

Parameter reports are a little more useful in that the user can select options from a drop down box to limit the output.  The "Classes By Instructor" report is an example.  When you run the report, a small form appears that allows you to choose an instructor.

Simple Reports:  To add a simple report to the Reports List, simply name the report with an "rpt" prefix.  By using a prefix, you can prevent reports (like the "ClassCertificate" report) from showing up in the list.  (ClassCertificate runs from the "Scheduled Class Entry" screen only.)

Parameter Reports:  To add a parameter report to the Reports List is a little more complex.  First of all, you have to create a form which has controls to hold the parameters and reference those controls in the Report Source query.  Next, name the form with an "rpt" prefix.  Lastly, you'll want to name the report itself with an "rpf" prefix.  This will prevent these reports from appearing in the Reports List.

Example:  The form "rptClasses By Instructor" is the form which will run the "rpfClasses by Instuctor" report.  The Record Source for the report (a saved query called: Scheduled Classes Query by Instructor) references the combo box value on the form to restrict the values in the report.

Maintain Information

The Maintain Information screen allows you to edit your reference tables.  In it, you can add or edit Applications, Buildings, Classrooms, Courses, and so forth.  These options will then be available to the drop down lists in the data entry screens.

If you add new reference tables, you'll also want to create a simple edit form for the table.  If you name the form with a prefix of "Maintain ", it will automatically appear in the Table Mainenance list.

The Getting Started screen is a little different from the rest as it allows you to turn the Getting Started screen on and off.


You can find this sample here: http://www.rogersaccesslibrary.com/forum/topic232.html.

Monday, October 10, 2011

How do I calculate a Median in Access? Part 2

The DMedian() Function:

In my last post, (How do I calculate a Median in Access? Part 1) I defined Median and described in general terms how to calculate a median in Access. This time, I'm going to describe in detail the DMedian() user-defined function.

First of all, you have to create a Public Function in a General Module. Create a new module by selecting Module in the Database Window and click the New button. Immediately click the Save button and name the module "basDMedian". Next, type the following function into the module.

Public Function DMedian(FieldName As String, _
      TableName As String, _
      Optional Criteria As Variant) As Variant

' Created by Roger J. Carlson
'
http://www.rogersaccesslibrary.com
'
Terms of use: You may use this function in any application, but
' it must include this notice.

'Returns the median of a given field in a given table.
'Returns -1 if no recordset is created

' You use this function much like the built-in Domain functions
' (DLookUp, DMax, and so on). That is, you must provide the
' 1) field name, 2) table name, and 3) a 'Where' Criteria.
' When used in an aggregate query, you MUST add each field
' in the GROUP BY clause into the into the Where Criteria
' of this function.

' See Help for more on Domain Aggregate functions.

On Error GoTo Err_Median

    Dim db As DAO.Database
    Dim rs As DAO.Recordset
    Dim strSQL As String
    Dim RowCount As Long
    Dim LowMedian As Double, HighMedian As Double

    'Open a recordset on the table.
    Set db = CurrentDb
    strSQL = "SELECT " & FieldName & " FROM " & TableName
    If Not IsMissing(Criteria) Then
        strSQL = strSQL & " WHERE " & Criteria & " ORDER BY " & FieldName
    Else
        strSQL = strSQL & " ORDER BY " & FieldName
    End If
    Set rs = db.OpenRecordset(strSQL, dbOpenDynaset)

    'Find the number of rows in the table.
    rs.MoveLast
    RowCount = rs.RecordCount
    rs.MoveFirst
   
    'Determine Even or Odd
    If RowCount Mod 2 = 0 Then
        'There is an even number of records. Determine the low and high
        'values in the middle and average them.
        rs.Move Int(RowCount / 2) - 1
        LowMedian = rs(FieldName)
        rs.Move 1
        HighMedian = rs(FieldName)
        'Return Median
        DMedian = (LowMedian + HighMedian) / 2
    Else
        'There is an odd number of records. Return the value exactly in
        'the middle.
        rs.Move Int(RowCount / 2)
        'Return Median
        DMedian = rs(FieldName)
    End If

Exit_Median:
    'close recordset
    rs.Close
    Exit Function

Err_Median:
    If Err.Number = 3075 Then
        DMedian = 0
        Resume Exit_Median
    ElseIf Err.Number = 3021 Then
        'EOF or BOF ie no recordset created
        DMedian = -1
        Resume Exit_Median
    Else
        MsgBox Err.Description
        Resume Exit_Median
    End If
End Function

To use this function in a query, simply use the query above that calculates the average with the DAvg, and replace DAvg with DMedian, like this:

SELECT Hospital, DMedian("TimeToProc", "tblTimeToProcedure",
    "[Hospital] = '" & Hospital &"'") AS MedianTimeToProc
FROM tblTimeToProcedure
GROUP BY Hospital

Which will return this:

Hospital

MedianTimeToProc

A

2.60

B

3.5

Caveats:

You have to be careful, however, because it is very easy to produce data that looks correct, but is not. If you're not careful to include every field contained in the Where clause and Group By clause of your main query in the Criteria of the DMedian function, your data will not be correct.

Let's look at a slightly more complex example. Suppose we want to aggregate our TimeToProc data at the Hospital and Unit level. We might have a table that looks like this:

tblTimeToProcedure

PatientID

Hospital

Unit

TimeToProc

1

A

C1

1.5

2

A

C2

2

3

A

C1

2.2

4

A

C2

3

5

A

C1

2

6

A

C1

4

7

A

C2

5

8

A

C2

100

9

B

A1

2.5

10

B

A1

2

11

B

A1

4.2

12

B

A2

3

13

B

A2

2.2

14

B

A2

4

15

B

A1

5

16

B

A1

6

Suppose I create a totals query in Access that aggregates the data on Hospital and Unit, but only provide the Hospital to the DMedian function's criteria. Like this:

SELECT Hospital, Unit, DMedian("TimeToProc","tblTimeToProcedure",
     "[Hospital] = '" & [Hospital] & "'") AS MedianTimeToProc
FROM tblTimeToProcedure
GROUP BY Hospital, Unit;

I'll get a result that looks like this:

Hospital

Unit

MedianTimeToProc

A

C1

2.60

A

C2

2.60

B

A1

3.5

B

A2

3.5

This is obviously wrong. The DMedian function is aggregating ONLY at the Hospital level, while the main query is aggregating at both Hospital and Unit.

In order to produce the correct median values, we have to supply both the Hospital and the Unit to the DMedian function.

DMedian("TimeToProc", "tblTimeToProcedure", "[Hospital] = '" & Hospital &"' AND [Unit] = '" & Unit & "'")

The finished query will look like this:

SELECT Hospital, Unit, DMedian("TimeToProc", "tblTimeToProcedure",
     "[Hospital] = '" & Hospital &"'AND [Unit] = '" & Unit & "'") AS MedianTimeToProc
FROM tblTimeToProcedure
GROUP BY Hospital, Unit;

This will produce the correct results:

Hospital

Unit

MedianTimeToProc

A

C1

2.10

A

C2

4

B

A1

4.2

B

A2

3

So the rule is that every field that participates in the Where clause or Group By clause of the main aggregate query must also be represented in the Criteria argument of the domain aggregate function.

Making Sure Your Query is Correct

One way to make sure you are aggregating the data correctly in both the main query and the domain aggregate function is to create an aggregate query using the SQL AVG function, and then create the same query using the DAvg domain aggregate function. If the two queries produce the same values, you know you have created it correctly. Then just replace DAvg with your DMedian function.

For instance, first create an AVERAGE aggregate query using the SQL AVG function. The SQL statement would look like this:

SELECT Hospital, Unit, AVG(TimeToProc) AS AvgerageTimeToProc
FROM tblTimeToProcedure
GROUP BY Hospital, Unit

Hospital

Unit

AverageTimeToProc

A

C1

2.43

A

C2

27.50

B

A1

3.94

B

A2

3.07

Now create the same query, but this time use the DAvg function.

SELECT Hospital, Unit, DAvg("TimeToProc", "tblTimeToProcedure",
    "[Hospital] = '" & Hospital &"' AND [Unit] = '" & Unit & "'") AS
    AverageTimeToProc
FROM tblTimeToProcedure
GROUP BY Hospital, Unit;

Hospital

Unit

AverageTimeToProc

A

C1

2.43

A

C2

27.50

B

A1

3.94

B

A2

3.07

Since the two queries produce identical results, we know that we have set up the domain function correctly. Now just replace DAvg with your DMedian function:

SELECT Hospital, Unit, DMedian("TimeToProc", "tblTimeToProcedure",
     "[Hospital] = '" & Hospital &"' AND [Unit] = '" & Unit & "'") AS
     MedianTimeToProc
FROM tblTimeToProcedure
GROUP BY Hospital, Unit;

Hospital

Unit

MedianTimeToProc

A

C1

2.10

A

C2

4

B

A1

4.2

B

A2

3

On-line Database Sample:

On my website, (http://www.rogersaccesslibrary.com), there is a small sample database called Median.mdb. This sample has the above example and another, more complex, example in an Access database, so you can see how the DMedian function works.

There are two versions of the DMedian function. DMedian is in the basMedianADO module, and DMedian is in the basMedianDAO. You must use the DMedian97 in an Access 97 database.

Conclusion:

Because Microsoft Access® does not have a Median aggregate function, finding the median value of a group of data can be a challenge. But with a little programming expertise, you can create your own DMedian domain-aggregate function that you can use to find the Median value for an aggregate query.

Friday, October 7, 2011

How do I calculate a Median in Access?

Users of Microsoft Excel® are familiar with the MEDIAN function. Select a range of cells, push the function button, select MEDIAN under statistical functions, and you have your median value. However, no such function exists in Microsoft Access®. So if you need to figure a median in Access, what do you do? One solution is to create your own Median domain aggregate function or DMedian().

But to understand how to program a median function, you must first understand how a median is calculated.

Calculating a Median:

Almost everyone knows what an average is. Add up all the values in your list and divide that by the number of values. In general, it looks like this: (a1+a2+...+an)/n. In most cases, this gives a pretty good aggregate picture of your data. However, if you have values that fall way out of the general range of the others, it can give you a skewed picture.

This is where the median becomes important. A median works differently. To find the median, you sort your list (ascending or descending, makes no difference), count the number of values in your list, and then divide that number by two. If the list has an odd number of values, the result will be a fraction (n.5). Take the integer portion of the resultant (n) and go to the (n+1)th value in your sorted list. That number becomes the median. If the list has an even number of values, the result will be a whole number (n). To figure a median with an even number of values, you take the integer portion of the resultant, (n) and average the nth and (n+1)th values.

Example - Odd number of values:

1.5

2

2.2

3

2

4

5

Average: (1.5+2+2.2+3+2+4+5)/7 = 2.814286.

Median: First, order the list (1.5, 2, 2, 2.2, 3, 4, 5). Counting the number of values returns 7. Divide 7 by 2 and you get 3.5. Taking the integer portion of 3.5 yields 3. Go to the (3+1)th (or 4th) value in the ordered list and you have your median of 2.2.

Example - Even number of values:

1.5

2

2.2

3

2

4

5

1

Average: (1.5+2+2.2+3+2+4+5+1)/8 = 2.5875.

Median: Again, order the list (1, 1.5, 2, 2, 2.2, 3, 4, 5). There are 8 values in the list. Dividing 8 by 2 equals 4. Select the 4th and (4+1)th (that is 5th) value in the ordered list results in 2 and 2.2. Averaging these numbers results in your median value of 2.1.

As you can see, in both cases, the values of the average and median are fairly close. In the Odd case: 2.814286 vs. 2.2. In the Even case: 2.5875 vs. 2.1. But what if we had an outlier; say 100 (in place of 5), in the list?

1.5

2

2.2

3

2

4

100

1

The median stays at 2.1, but the average jumps to 14.4625. Not very representative of your data. So there are times when it is statistically more accurate to use the median rather than the average.

Calculating the Median in Access

But the question remains: how do you create a median in Microsoft Access? One answer is to create your own domain aggregate function: DMedian().

So what are domain aggregate functions? Access has a number of built-in domain aggregate functions that work similarly to the SQL aggregate functions: MAX, MIN, SUM, COUNT, AVG (and others). They are DMax(), DMin, DSum, DCount, and DAvg. These functions act like mini totals (aggregate) queries that return a single value. You can use these functions as the source for a control on a form or report, or you can use them in a query. For more information on Domain functions, see my blog series: Domain Functions Demystified.

There are three arguments you must provide to a domain function. Two are required: Fieldname, Tablename, and the third is optional: a Criteria (essentially a Where clause without the word WHERE). The domain function will then calculate the desired function (min, max, etc.) for that Field, against that Table, filtering it on the Criteria. In general: Dfunction("fieldname", "tablename", "criteria").

Before we look at creating our own DMedian() function, let's look at how the DAvg() function works.

Suppose we have the following table:

tblTimeToProcedure

PatientID

Hospital

TimeToProc

1

A

1.5

2

A

2

3

A

2.2

4

A

3

5

A

2

6

A

4

7

A

5

8

A

100

9

B

2.5

10

B

2

11

B

4.2

12

B

3

13

B

2.2

14

B

4

15

B

5

16

B

6

(TimeToProc is the number of hours between patient admission and the time a give procedure was administered.)

To calculate the average TimeToProc for the entire table with the DAvg function, you would provide the Field and Table without a Criteria. Like this:

DAvg("TimeToProc", "tblTimeToProcedure")

In this case, no Criteria required because we don't want to filter the data. However, suppose we wanted just the average of Hospital A? In that case, we would do this:

DAvg("TimeToProc", "tblTimeToProcedure", "[Hospital]='A'")

(Because Hospital is text data, you have to provide quotes (or single quotes) around it. Numeric data does not require delimiters. For more information on this, look in the Access Help at the DMin, DMax aggregate functions. Type DMin in the keywords.)

You can also use the DAvg function in a Totals Query in Access to return the average for each hospital. Like this:

SELECT Hospital, DAvg("TimeToProc", "tblTimeToProcedure",
"[Hospital] = '" & Hospital &"'") AS AverageTimeToProc
FROM tblTimeToProcedure
GROUP BY Hospital

Which will return this:

Hospital

AverageTimeToProc

A

14.9625

B

3.6125

The obvious question, of course, is why not just use the SQL aggregate function (AVG) to do the same thing:

SELECT Hospital, AVG(Hospital) AS AverageTimeToProc
FROM tblTimeToProcedure
GROUP BY Hospital

That's a good question, and in fact, it would be better to us the SQL function. But what if Access didn't have an AVG function? This is the case with the MEDIAN. No such function exists, so we have to create our own DMedian function to replace it.

Next time, I'll look at the details of the DMedian() function.

Thursday, October 6, 2011

New Sample: Form_ContinuousSimulated

By A. D. Tejpal

This sample db demonstrates a simulated continuous form having unbound controls, facilitating row-wise display of unlimited colors.


It displays 12 records at a time. Full coverage of data is provided via suitable navigation buttons. Apart from being able to edit the records, the user can add new records or delete the current record by clicking appropriate command buttons. In addition, two alternative modes for search have been provided: (a) By record number or (b) By ID number. All these actions are feasible directly on the form. Current record remains identified by special highlight in first column.

First two columns (locked) display the record number and TrainID. Next two columns, holding TrainCode and ColorValue, are editable. Last column serves as ColorStrip, each row displaying the color represented by ColorValue in the previous column.

There is two way synchronization between ColorValue and ColorStrip. Any value entered in the former gets reflected as corresponding color in the latter. On the other hand, double click on ColorStrip invokes the color dialog box, where the user has unlimited choice and the color finally selected gets displayed in the color strip. Simultaneously, appropriate value gets assigned in ColorValue column.

You can find the sample here:
http://www.rogersaccesslibrary.com/forum/topic574_post592.html

Tuesday, October 4, 2011

What To Do When You Take Over A Database Application

Taking over an existing database project is much like designing one from scratch, except some of the work is done for you. Unfortunately, some of that work may be wrong, so you can't necessarily rely on it.

First of all, are there relationships set up in the Relationship Window? Hopefully there are.  This will give you a map to see how the tables are related.

Write all the relationships in pairs of sentences: See Entity Relationship Diagramming for more information.

1:M
Each Customer can have one or more Orders.
Each Order can be for one and only one Customer.

image

M:M
Each Student can be in one or more Classes
Each Class can have one or more Students

image

Ask yourself (or your customer) if each and every one of these sentences is true. I will often go through this process with the customer. As they learn the database structure in this non-technical way, they will begin to spot relationship errors on their own.

Don't be constrained by the existing product. It's quite possible that the original database design is wrong. Don't assume the previous developer knew what he or she was doing. Even if he did, chances are good that if it's been in production for more than a couple of years, the business rules have changed. This is where the customer having a grasp of the database design process can be very useful.

If there are no relationships, you will have to infer these relationships based on the queries.  As you discover table relationships, you should create them in the Relationships Window.  If they're not there already, it is doubtful that you will be able to turn Referential Integrity ON, but at the very least, you will begin documenting the relationships.

Next, I would start with the reports.  Open a report and check the RecordSource property see which query it uses.  Then open that query, see what it is based on and so forth.  When I have done this, I've used a separate piece of paper for each report and query tree.  Then I will actually draw out the tree structure.  I'll also create a list of all the queries and underneath each, list the queries or objects (form or reports) that it directly applies to.  This can help if a single query is a base for many others.  You may be able to find a tool to do this for you, but the discovery process is very educational.

Do the same with the forms.

Next, look through the Code Modules (including the code behind forms and reports).  Often code is used to create queries or uses saved queries to create recordsets. 

If DAO is used to CREATE the query, it might look something like this:   

strSQL = "SELECT * FROM MyTable"
Set qdf = db.CreateQueryDef("qryMyQuery", strSQL)

or

Set qdf = db.CreateQueryDef("qryMyQuery", "SELECT * FROM MyTable")

The first method is preferable and it is worthwhile to convert any using the second method into the first. The reason for this is that you will also want to know what queries are being created in code. If you create the SQL as a separate string, you can use the Debug.Print line to have the code evaluate the SQL string and display the SQL code in the Immediate Window. Like this:

strSQL = "SELECT * FROM MyTable"
Debug.Print strSQL
Set qdf = db.CreateQueryDef("qryMyQuery", strSQL)

Complex SQL statements are often difficult to read in VBA code, so this is a useful debugging technique as well.

If a query is just being USED in code (not created in code) it might look like this:

Set qdf = db.QueryDefs("qryMyQuery")

or

Set rs= db.OpenRecordset("qryMyQuery")

or in ADO

rs.Open "qryMyQuery', cnn, adOpenKeyset, adLockOptimistic

There are a lot of variations on this.  However, the important thing is that the query (or table for that matter) is being used by the code.  Make a note of that as well.  You can use the Find and Replace feature to find each query name.  You can set it to search through all of the code modules.

Also, some Forms and Reports have SQL statements in their RecordSource properties, rather than saved queries.  You should also make a note of the elements that make up these.

Once you've done all the reports, forms, and code, see which queries are not accounted for.  Chances are they are not used anywhere.  Many mature database projects have unused objects lying around.  DO NOT delete these. Instead, I favor renaming them with an XXX prefix, which tells me this is OK to delete at some future time.  Sometimes I will also add the date to the name so I know how long it's been since I "deleted" it.  If you run into a problem, you can always name it back.

Lastly, I would try to make some kind of method out of all of this madness. Try to develop some sort of rational naming structure for your queries. There is no single correct way to do this.  Often if a series of queries is used ONLY by one report, I will name them after the report and indicate which level they are in.  However, for queries that are used as a base for multiple other queries, this doesn't work so well.  I've never come up with anything that worked in all cases.  And it doesn't matter.  Just try the best you can to do a rational job of renaming them.  CAUTION:  DO THIS ON PAPER FIRST!

Once you have renamed your queries on paper in some rational manner, get your hands on a renaming tool.  Rick Fisher has a good shareware add-in called "Find and Replace".  You can find it here: http://www.rickworld.com/download.html.  (It is worth registering for the extra features, though).  This product (and others like Speed Ferret) allow you to rename an object throughout the entire database including forms, queries, reports, macros, and code.

By the time you get done with all this, you will know this database like the back of your hand.