Crosstab query totals

R

ripper

I have Query1 that returns 2 fields:
CatID
Step1Decision

CatID can be 01 thru 29
Step1Decision can be N,X,P,D,R

Query1:
SELECT qryGrievances.CatID, qryGrievances.Step1Decision
FROM qryGrievances, qryStartEnd

Query2 uses Query1 joined to qryCategories to return all the categories and
their description plus those in Query1

Query2:
SELECT qryCategories.CatID, qryCategories.CatDesc, Query1.Step1Decision
FROM qryCategories LEFT JOIN Query1 ON qryCategories.CatID = Query1.CatID

Query3 uses Query2 in a crosstab so the Step1Decision (N,X,P,D,R) become
column headings and categories become rows, and adds a Total field:

Query3:
TRANSFORM Count(Query2.Step1Decision) AS [Count]
SELECT Query2.CatID, Query2.CatDesc, Count(Query2.CatID) AS Total
FROM Query2
GROUP BY Query2.CatID, Query2.CatDesc
PIVOT Query2.Step1Decision

Result looks like this:

CatID CatDesc Total <> D N R X
01 Accounting 7 6 1
02 Assignments 24 5 12 7
03 Conditions 1 0
04 Disciplinary 2 2

My questions are: how is the <> field generated? I can't refer to it in
code, which is a problem. Also, why does the total column show correct
totals for the D,N,R,X values added across, but if there are no records
returned for a category, it still shows 1? Also, if no records exist for one
of the decision values (P in the case above), that field is not returned by
the query at all. How can I create a report based on a query that may or may
not return some of the fields?

Thanks to all who can help!
Ripper
 
K

KARL DEWEY

<> represents the Null fields of the left join with query1.

This is untested but try it --
Query2:
SELECT qryCategories.CatID, qryCategories.CatDesc, Nz(Query1.Step1Decision,
"None") AS Decision
FROM qryCategories LEFT JOIN Query1 ON qryCategories.CatID = Query1.CatID;

Query3:
TRANSFORM Count(Query2.Step1Decision) AS [Count]
SELECT Query2.CatID, Query2.CatDesc, Count(Query2.CatID) AS Total
FROM Query2
GROUP BY Query2.CatID, Query2.CatDesc
PIVOT Query2.Decision;
 
D

Duane Hookom

The <> is generated from one or more records with no value in Step1Decision
field.

TRANSFORM Count(Query2.Step1Decision) AS [Count]
SELECT Query2.CatID, Query2.CatDesc, Count(Query2.CatID) AS Total
FROM Query2
GROUP BY Query2.CatID, Query2.CatDesc
PIVOT Query2.Step1Decision IN ("D","N","R","X","P");
 
J

John Spencer

The reason the Total is 1 when there are no records in Step1Decision is you
are counting CatID in the SELECT clause. Try counting Step1Decision instead.


TRANSFORM Count(Query2.Step1Decision) AS [Count]
SELECT Query2.CatID, Query2.CatDesc, Count(Query2.Step1Decision) AS Total
FROM Query2
GROUP BY Query2.CatID, Query2.CatDesc
PIVOT Query2.Step1Decision IN ("D","N","R","X","P");

Of course, the Total count could still be off if there were any other values
in Step1decision other than Null, D, N, R, X, or P.

So you might even have to limit the query a bit further with a where clause.
TRANSFORM Count(Query2.Step1Decision) AS [Count]
SELECT Query2.CatID, Query2.CatDesc, Count(Query2.Step1Decision) AS Total
FROM Query2
WHERE Query2.Step1Decision IN ("D","N","R","X","P") OR Step1Decision is Null
GROUP BY Query2.CatID, Query2.CatDesc
PIVOT Query2.Step1Decision IN ("D","N","R","X","P");


John Spencer
Access MVP 2002-2005, 2007-2010
The Hilltop Institute
University of Maryland Baltimore County
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Top