by AD Tejpal
This sample db demonstrates identification of data blocks as well as missing portions in a sequential series. Three types of source data are covered:
(a) Number series.
(b) Alpha-numeric series.
(c) Date series.
Subform on left shows all records, duly highlighting the start of each new block of sequential series. Subform at right depicts group-wise gist (for each PersonID) of sequential blocks as well as missing portions, duly indicating the start and end values for each set. Missing blocks are highlighted in light grey.
Version: Access 2000 file format.
You can find the sample here: http://www.rogersaccesslibrary.com/forum/query-grpsequentialsandmissing_topic556.html
.
Friday, January 28, 2011
Tuesday, January 18, 2011
New Sample: TableNormalizationByPureSQL
by A.D. Tejpal
This sample db demonstrates pure query based solution for normalization of data held by a non-normalized table (T_Source) and posting the converted contents to destination table (T_Normalized).
Steps:
1 - Create the empty destination table T_Normalized with a structure identical to that of table T_Source, but without the non-normalized fields (e.g. Red, Green, Blue, Yellow in this sample).
2 - Add two new fields to the newly created table T_Normalized. One meant for holding the names of non-normalized fields and the other for holding corresponding values. In the current sample, these two fields are named Color and Stock respectively.
3 - Create an auxiliary table named T_SourceFieldsConverted having a single field meant for holding names of non-normalized fields. In the current sample, this field is named Color. Populate this table with the names of non-normalized fields (i.e. Red, Green, Blue, Yellow in this sample).
4 - Execution of append query Q_AppNormalized will populate destination table T_Normalized with normalized data, duly converted from source table T_Source. This query is based upon Cartesian join between tables T_SourceFieldsConverted and T_Source.
Version: Access 2000 file format.
You can find the sample here: http://www.rogersaccesslibrary.com/forum/tablenormalizationbypuresql_topic554.html
.
This sample db demonstrates pure query based solution for normalization of data held by a non-normalized table (T_Source) and posting the converted contents to destination table (T_Normalized).
Steps:
1 - Create the empty destination table T_Normalized with a structure identical to that of table T_Source, but without the non-normalized fields (e.g. Red, Green, Blue, Yellow in this sample).
2 - Add two new fields to the newly created table T_Normalized. One meant for holding the names of non-normalized fields and the other for holding corresponding values. In the current sample, these two fields are named Color and Stock respectively.
3 - Create an auxiliary table named T_SourceFieldsConverted having a single field meant for holding names of non-normalized fields. In the current sample, this field is named Color. Populate this table with the names of non-normalized fields (i.e. Red, Green, Blue, Yellow in this sample).
4 - Execution of append query Q_AppNormalized will populate destination table T_Normalized with normalized data, duly converted from source table T_Source. This query is based upon Cartesian join between tables T_SourceFieldsConverted and T_Source.
Version: Access 2000 file format.
You can find the sample here: http://www.rogersaccesslibrary.com/forum/tablenormalizationbypuresql_topic554.html
.
Thursday, January 13, 2011
Domain Function Example: Rolling Average in Query
So far in this series on Domain Functions, I've discussed the general syntax (Domain Functions Demystified) and problems involved in building criteria expressions (Domain Functions Demystified: Criteria Expressions). Unfortunately, many of the examples I've given are relatively trivial. So for my next few blog posts, I thought I'd give what I consider truly useful applications of domain functions.
Other Examples:
- Simulate AutoNumber with DMax
- Running Sum with DSum
- Numbered Query with DCount
- "Difference Between" with DLookup/DMax
- Begin Date and End Date from Effective Date
For instance, suppose I wanted to display a rolling average for the last 12 weeks for the table below:
Figure1
For Week 26, I need to display the average for weeks 15-26 (39.85). For Week 25, it would be the average for weeks 14-25 (43.85), and so forth. For weeks with less than 12 in the recordset, it will average only those weeks available. So Week 9 would only average weeks 7-9 (53.67).
In other words, this:
Figure 2
The problem is that SQL does not have positional notation like Excel does. There's no way to simply point to the record above the one you're on -- or the previous 12, for that matter. The only way to do it is to somehow identify the previous records in terms of a Where condition. Since this Where condition must be evaluated for each line, O can do this with a domain aggregate function or a correlated subquery. In this case, two domain functions and two subqueries.
For either method to work, I must have a unique record ID. The Autonumber field is ideal for this. It doesn't matter if there are gaps in the sequence, but I have to sort on this field, so there cannot be duplicates and they must be in the order I need displayed. In the above sample, ID fits the bill.
Domain Function Method (DCount and DAvg)
Domain Aggregate functions are an Access-only method to return statistical information about a specific set of records, whether from a table or query. DCount in particular will return the number of records in a given recordset. DAvg will return the average of a given recordset. Both functions have three arguments: 1) an expression that identifies a field, 2) a string expression that identifies a domain (that is, the table or query), and 3) a Criteria, which is essentially an SQL Where clause without the word WHERE.
The first step in this process is to create an unbroken sequence number for the records. It must be unbroken so I can subtract 12 from it to average the correct number of weeks. The second step produces the average.
Step1: DCount_RollingAverage1:
SELECT DCount("ID","Table1","ID <=" & [ID]) AS Sequence, tWeek, tValue
FROM Table1
ORDER BY ID DESC;
The Order By clause in the query is important. This will sort the query on the ID field. I'll need to have that order to use the criteria argument in the DCount.
Here's how it works.
For each record in the query, Access runs the DCount function. The DCount returns the number of records in the domain where the ID in the function is less than or equal to the ID in that record of the query.
So in the first record, the ID is 1. So the DCount opens the domain (essentially opens the Customers table again) and it sees that there is only 1 record whose ID is less than or equal to 1. So it returns 1.
Then it processes the second record. The ID of that record is 3, and the DCount function sees that there are only 2 records which have an ID whose value is less than or equal to 2. So it returns 2.
It is not necessary that the Order By field is an unbroken sequence. As long as that field has unique values and is sorted, it will work.
Figure 3
Step2: DCount_RollingAverage2:
Now that DCount_RollingAverage1is a recordset with an unbroken sequence, I can use as it as the record source for the query that will create the rolling averages:
SELECT Sequence, tWeek, tValue, DAvg("tValue","[DCount_RollingAverage1]",
"Sequence Between " & [Sequence] & " And " & [Sequence]-12) AS [12-Week Rolling Average]
FROM DCount_RollingAverage1;
"Sequence Between " & [Sequence] & " And " & [Sequence]-12) AS [12-Week Rolling Average]
FROM DCount_RollingAverage1;
So in the first record, the Sequence is 26. So the DAvg opens the domain (essentially opens Table1 again) and averages weeks 15-26. Then it processes the second record, averaging weeks 14-25 and so forth.
Figure 4
Subquery Method
There is no way to combine these two queries into one. To do that, I'd need to use a correlated subquery, which I may discuss at a later date. However, you can find both methods on my website in this sample: RollingAverages.mdb.
Monday, January 10, 2011
Domain Function Example: "Difference Between" in Query
So far in this series on Domain Functions, I've discussed the general syntax (Domain Functions Demystified) and problems involved in building criteria expressions (Domain Functions Demystified: Criteria Expressions). Unfortunately, many of the examples I've given are relatively trivial. So for my next few blog posts, I thought I'd give what I consider truly useful applications of domain functions.
Other Examples:
- Simulate AutoNumber with DMax
- Running Sum with DSum
- Numbered Query with DCount
- Rolling Average with DAvg and DCount
- Begin Date and End Date from Effective Date
For instance, suppose I wanted to display the difference in days between orders in the table below:
Figure1: Need to calculate the difference between records.
The difference in days between records 1 and 2 is 4, between 2 and 3 is 7, between 3 and 4 is -22, and so forth.
The problem is that SQL does not have positional notation like Excel does. There's no way to simply point to the record above the one you're on. The only way to do it is to somehow identify the previous record in terms of a Where condition. Since this Where condition must be evaluated for each line, I can do this with a domain aggregate functions (DMax & DLookup).
For this method to work, I must have a unique record ID. The Autonumber field is ideal for this. It doesn't matter if there are gaps in the sequence, but I have to sort on this field, so there cannot be duplicates and they must be in the order I need displayed. In the above sample, OrderDetailsID fits the bill.
The technique is similar to creating a Numbered Query or a Running Sum in a query, but instead of just counting or summing all the records above the current record, I have to find just the previous record. This adds an additional complication, which requires an additional domain function.
Specifically, I need three steps:
- Use a domain function (DMax) to find the unique identifier the previous row.
- Then feed that value in to another domain function (DLookup) that identifies the previous value,
- And then subtract the previous value from the current value.
Difference Between - Over All
Domain Aggregate functions are an Access-only method to return statistical information about a specific set of records, whether from a table or query. They have three arguments: 1) an expression that identifies a field, 2) a string expression that identifies a domain (that is, the table or query), and 3) a Criteria, which is essentially an SQL Where clause without the word WHERE.
Here are the steps:
- I need a DMax function to return the OrderDetailID of the previous record in the table: DMax("OrderDetailID","tblOrderDetails","OrderDetailID < " & [OrderDetailID])
- Next, I'll feed that to a DLookup function, which will return the date value from the previous row given number of records. DLookUp("OrderDate","tblOrderDetails","OrderDetailID = " & DMax("OrderDetailID","tblOrderDetails","OrderDetailID < " & [OrderDetailID]))
- Lastly, I'll subtract the this value from [OrderDate]of the current record and give the column an alias:[OrderDate]-DLookUp("OrderDate","tblOrderDetails","OrderDetailID = " & DMax("OrderDetailID","tblOrderDetails","OrderDetailID < " & [OrderDetailID])) AS DaysBetween
SELECT tblOrderDetails.OrderDetailID, tblOrderDetails.OrderID, tblOrderDetails.OrderDate, nz([OrderDate]-DLookUp("OrderDate","tblOrderDetails","OrderDetailID = " & nz(DMax("OrderDetailID","tblOrderDetails","OrderDetailID < " & [OrderDetailID]),0)),0) AS DaysBetween
FROM tblOrderDetails
ORDER BY tblOrderDetails.OrderDetailID;
The two NZ() functions are needed to display a zero on the first line. Otherwise, it would return an ERROR.
The Order By clause in the query is important. This will sort the query on the OrderDetailID field. I'll need to have that order to use the criteria argument in the DMax.
It is not necessary that the Order By field is an unbroken sequence. As long as that field has unique values and is sorted, it will work.
Figure 2: Shows the time difference in days between subsequent records.
Difference Between - Over Group
SELECT tblOrderDetails.OrderDetailID, tblOrderDetails.OrderID, tblOrderDetails.OrderDate,
Nz([OrderDate]-DLookUp("OrderDate","tblOrderDetails","OrderDetailID = " & Nz(DMax("OrderDetailID","tblOrderDetails","OrderID = " & [OrderID] & " And OrderDetailID < " & [OrderDetailID]),0)),0) AS DaysBetween
FROM tblOrderDetails
ORDER BY tblOrderDetails.OrderDetailID;
Figure 3: As the OrderID changes, the DaysBetween resets to zero.
The only difference between this query and the OverAll query is the addition of
"OrderID = " & [OrderID]
to the "Where" condition of the DMax function. This sets the value of the first record of each group to zero.
Subquery Method
As I said, these can also be done with a correlated subquery, which I may discuss at a later date. However, you can find both methods on my website in this sample: DaysBetween.mdb
Monday, January 3, 2011
Domain Function Example: Running Sum with DSum
So far in this series on Domain Functions, I've discussed the general syntax (Domain Functions Demystified) and problems involved in building criteria expressions (Domain Functions Demystified: Criteria Expressions). Unfortunately, many of the examples I've given are relatively trivial. So for my next few blog posts, I thought I'd give what I consider truly useful applications of domain functions.
Other Examples
- Simulate AutoNumber with DMax
- Numbered Query with DCount
- Difference Between with DMax
- Rolling Average with DAvg and DCount
- Begin Date and End Date from Effective Date
Running Sum
One thing that is easy to do in a report, but difficult to produce in a query, is a Running Sum. A running sum adds the value of a field in a record to the value of the same field in the previous record.In a report, there are two common types of running sums: Over All and Over Group. To create a running over all, I place a textbox control on the details section, setting the Control Source property to the field I want summed and setting the Running Sum property to Over, as in Figure 1. Figure 2 shows the results. To create one over a group (say each Order number), I'd set the Running Sum property to Over Group
Figure 1
Figure 2
But it's not so easy in a query. The problem is that SQL does not have positional notation like Excel does. There's no way to simply point to the record above the one you're on. The only way to do it is to somehow identify the previous record in terms of a Where condition. Since this Where condition must be evaluated for each line, I can do this with a domain aggregate function (DSum) is ideal.
For this method to work, I must have a unique record ID. The Autonumber field is ideal for this. It doesn't matter if there are gaps in the sequence, but I have to sort on this field, so there cannot be duplicates and they must be in the order I need displayed. In the above sample, OrderDetailsID fits the bill.
There are two different ways I might want to see the running sum:
- Over the whole list (see Figure 3)
- Over each group, where the running sum resets to zero as the Order ID changes (see Figure 5).
There are two methods to create a running sum: DSum domain aggregate function and a correlated subquery. I'm going to concentrate on the DSum method here.
DSum
SELECT OrderDetailID, OrderID, ProductID, Price,
DSum("Price","tblOrderDetails","OrderDetailID <=" & [OrderDetailID]) AS RunningSum
FROM tblOrderDetails;
The DSum function works much the same as the DCount in the Numbered Query example, but instead of counting the records, it sums them. Unfortunately, the DSum does not return a formatted number.
Figure 3
So if you are summing a currency field, you'll have to apply the formatting yourself. To do that, we can modify the DSum function adding the Format function to display the number as currency. Like so:
Format(DSum("Price","tblOrderDetails","OrderDetailID <=" & [OrderDetailID]), "Currency") AS RunningSumFormatted
Figure 4
Running Sum Over Group
In order to get the running sum for each grouping of OrderID, all I need to do is add another condition to the "Where" argument of the DSum:
DSum("Price","tblOrderDetails","OrderID = " & [OrderID] & " And OrderDetailID <=" & [OrderDetailID]) AS RunningSum
In this case, "OrderID = " & [OrderID]
The complete SQL statement (including formatting):
SELECT OrderDetailID, OrderID, ProductID, Price,
Format(DSum("Price","tblOrderDetails","OrderID = " & [OrderID] & " And OrderDetailID <=" & [OrderDetailID]),"Currency") AS RunningSum
FROM tblOrderDetails;
Figure 5
Subquery Method
Both types of running sum can also be done with correlated subqueries. I may discuss this at a later date. However, you can find both methods on my website, in this sample: RunningSumInQuery.mdb.
.
Subscribe to:
Posts (Atom)