You haven't USED the parameters in a where clause. All you've done is
declare the parameters as being a specific type.
Assuming that you are trying to limit the report to records that have
tblFsLog.Date between the two parameters, you would need something like
the following.
PARAMETERS [Beginning Date:] DateTime, [Ending Date:] DateTime;
TRANSFORM Count(tblFsLog.LogID) AS CountOfLogID
SELECT tblEmployees.ShortName
, tblFsLog.Date
, Count(tblFsLog.LogID) AS CountOfLogID1
FROM tblFsReason INNER JOIN
(tblEmployees INNER JOIN tblFsLog
ON tblEmployees.EmployeeID = tblFsLog.CsrID)
ON tblFsReason.FsReasonID = tblFsLog.ReasonID
WHERE tblFsLog.Date Between [Beginning Date:] and [Ending date:]
GROUP BY tblEmployees.ShortName, tblFsLog.Date
ORDER BY tblEmployees.ShortName, tblFsReason.Reason
PIVOT tblFsReason.Reason;
'====================================================
John Spencer
Access MVP 2002-2005, 2007-2008
Center for Health Program Development and Management
University of Maryland Baltimore County
'====================================================
I have declared the parameters as suggested in this thread. However, the
query is not limiting itself to parameters that are imputed. Here is what
the SQL looks like:
PARAMETERS [Beginning Date:] DateTime, [Ending Date:] DateTime;
TRANSFORM Count(tblFsLog.LogID) AS CountOfLogID
SELECT tblEmployees.ShortName, tblFsLog.Date, Count(tblFsLog.LogID) AS
CountOfLogID1
FROM tblFsReason INNER JOIN (tblEmployees INNER JOIN tblFsLog ON
tblEmployees.EmployeeID = tblFsLog.CsrID) ON tblFsReason.FsReasonID =
tblFsLog.ReasonID
GROUP BY tblEmployees.ShortName, tblFsLog.Date
ORDER BY tblEmployees.ShortName, tblFsReason.Reason
PIVOT tblFsReason.Reason;
As you can see I have the parameters at the beginning. However, the query
is pulling all data. What have I done wrong?
David
John Spencer said:
With a crosstab query you MUST declare your parameters and if any
other queries are used in the crosstab their parameters must also be
declared.
Open the query in design mode
Select Query: Parameters from the Menu
Fill in the EXACT name of the parameter in column 1
Select the data type of the parameter in column 2
Or open the query in SQL view and type at the beginning
Parameters [Enter Start Date] DateTime, [Enter End Date] DateTime;
....
I am trying to set up a crosstabs query with a parameter query to return
information based on recored between certain dates. I have tried the
following syntax in the Criteria section of the date field:
Between [enter start date] And [enter end date]
but I can't make it work.
Help!!