Hello, hope somebody here can help me... I have a query that lists
defects recorded in a user defined date range. That query is then used
as the source for a Cross Tab query that cross-tabs count of defect
type by calendar month. Defect types are stored in one table, defect
transactions in another along with date etc. When I cross-tab the
results, defect types that have no defects recorded against them
appear as a blank (null) value. That is, the zero value is suppressed.
Unfortunately, in the management reports that are produced, they (QA
Managers) want to see a Zero value, not a null value. (they postulate
that a null could be interpreted as "we forgot to count those
values...", NOT "we had no defects of that type..)
Is there a simple way to "un"-suppress zero values. I had thought of
doing an Immediate If, (that is, Iif count=Null, show "0", otherwise
show Count) but cannot get that to work...
I also thought of giving each transaction a notional value of "1",
then summing the results in a cross tab, but since a defect count is
null because we haven't recorded any transactions of that type, you
can't sum something that isn't there! A third option was to use the
immediate if in the "OnFormat" event of the report itself - still
can't make it work...
Any help would be hugely appreciated. Thanks in advance.
THE SQL statement for the current query is as follows:
TRANSFORM Count(QryComplaintSummary.RecordID) AS [The Value]
SELECT QryComplaintSummary.DefectTypeDesc,
Count(QryComplaintSummary.RecordID) AS [Total Of RecordID]
FROM QryComplaintSummary
GROUP BY QryComplaintSummary.DefectTypeDesc
PIVOT Format([Complaint Date],"mmm") In
("Jan","Feb","Mar","Apr","May","Jun","Jul","Aug"," Sep","Oct","Nov","Dec"); 4 5408
Hello
Surprise, surprise: you have to do it other way! I usually have to
supress printing zeros...
If you can define transactions column in the table as number,
cross-tab query will calculate zeros as default, I think.
Galina da********@optusnet.com.au (David Peach) wrote in message news:<ee**************************@posting.google. com>... Hello, hope somebody here can help me... I have a query that lists defects recorded in a user defined date range. That query is then used as the source for a Cross Tab query that cross-tabs count of defect type by calendar month. Defect types are stored in one table, defect transactions in another along with date etc. When I cross-tab the results, defect types that have no defects recorded against them appear as a blank (null) value. That is, the zero value is suppressed. Unfortunately, in the management reports that are produced, they (QA Managers) want to see a Zero value, not a null value. (they postulate that a null could be interpreted as "we forgot to count those values...", NOT "we had no defects of that type..)
Is there a simple way to "un"-suppress zero values. I had thought of doing an Immediate If, (that is, Iif count=Null, show "0", otherwise show Count) but cannot get that to work... I also thought of giving each transaction a notional value of "1", then summing the results in a cross tab, but since a defect count is null because we haven't recorded any transactions of that type, you can't sum something that isn't there! A third option was to use the immediate if in the "OnFormat" event of the report itself - still can't make it work...
Any help would be hugely appreciated. Thanks in advance.
THE SQL statement for the current query is as follows:
TRANSFORM Count(QryComplaintSummary.RecordID) AS [The Value] SELECT QryComplaintSummary.DefectTypeDesc, Count(QryComplaintSummary.RecordID) AS [Total Of RecordID] FROM QryComplaintSummary GROUP BY QryComplaintSummary.DefectTypeDesc PIVOT Format([Complaint Date],"mmm") In ("Jan","Feb","Mar","Apr","May","Jun","Jul","Aug"," Sep","Oct","Nov","Dec");
On 8 Aug 2004 23:46:47 -0700, da********@optusnet.com.au (David Peach)
wrote: Hello, hope somebody here can help me... I have a query that lists defects recorded in a user defined date range. That query is then used as the source for a Cross Tab query that cross-tabs count of defect type by calendar month. Defect types are stored in one table, defect transactions in another along with date etc. When I cross-tab the results, defect types that have no defects recorded against them appear as a blank (null) value. That is, the zero value is suppressed. Unfortunately, in the management reports that are produced, they (QA Managers) want to see a Zero value, not a null value.
Hi David
There may be some simple way, but I think you need to run the crosstab
on a query which already contains all the required table entries. For
example you can form a cross product (all pairs month/defect) by a
query "AllRequiredPairs" such as
SELECT DefectTypes.DefectType, MonthsTable.mnth
FROM DefectTypes, MonthsTable;
(MonthsTable is just a list "Jan", "Feb", "Mar "etc)
You can then form a query "Group1" which is the union of the required
pairs with the actual defects which have occurred.
SELECT DefectOccurrences.DefectType, Format([Complaint Date],"mmm")
AS mnth, "actual defect"
FROM DefectOccurrences
UNION Select DefectType, mnth, "dummy entry" from
AllRequiredEntries;
(I have added the third unnamed column to the union to make sure that
all records are unique otherwise it won't work. These two queries
could be combined)
Finally the crosstab can be something like
TRANSFORM Count([DefectType])-1
SELECT group1.DefectType FROM group1
GROUP BY group1.DefectType
PIVOT group1.mnth In
("Jan","Feb","Mar","Apr","May","Jun","Jul","Aug"," Sep","Oct","Nov","Dec");
where the minus one removes the "dummy" required items.
David
David, Thanks for your help, but there's an easier way - provided to
me by a genius in another Access forum...(its probably not polite to
say here which forum...!) Following is his code not mine....
=========================
Replace
Count(QryComplaintSummary.RecordID)
with
Nz(Count(QryComplaintSummary.RecordID),0)
The Nz function returns its first argument but replacess null values
by the second argument. Usually, the result of Nz is text. If you need
numeric values for further calculations, use
CLng(Nz(Count(QryComplaintSummary.RecordID),0))
=============================
I'd never used the Nz function before - very handy. This worked a
treat and is very simple & elegant.
Thanks for the follow -up though - much appreciated.
dp d.***************@blueyonder.co.uk (David Schofield) wrote in message news:<4117b0ef.745334354@localhost>... On 8 Aug 2004 23:46:47 -0700, da********@optusnet.com.au (David Peach) wrote:
Hello, hope somebody here can help me... I have a query that lists defects recorded in a user defined date range. That query is then used as the source for a Cross Tab query that cross-tabs count of defect type by calendar month. Defect types are stored in one table, defect transactions in another along with date etc. When I cross-tab the results, defect types that have no defects recorded against them appear as a blank (null) value. That is, the zero value is suppressed. Unfortunately, in the management reports that are produced, they (QA Managers) want to see a Zero value, not a null value.
Hi David
There may be some simple way, but I think you need to run the crosstab on a query which already contains all the required table entries. For example you can form a cross product (all pairs month/defect) by a query "AllRequiredPairs" such as
SELECT DefectTypes.DefectType, MonthsTable.mnth FROM DefectTypes, MonthsTable;
(MonthsTable is just a list "Jan", "Feb", "Mar "etc)
You can then form a query "Group1" which is the union of the required pairs with the actual defects which have occurred.
SELECT DefectOccurrences.DefectType, Format([Complaint Date],"mmm") AS mnth, "actual defect" FROM DefectOccurrences UNION Select DefectType, mnth, "dummy entry" from AllRequiredEntries;
(I have added the third unnamed column to the union to make sure that all records are unique otherwise it won't work. These two queries could be combined)
Finally the crosstab can be something like
TRANSFORM Count([DefectType])-1 SELECT group1.DefectType FROM group1 GROUP BY group1.DefectType PIVOT group1.mnth In ("Jan","Feb","Mar","Apr","May","Jun","Jul","Aug"," Sep","Oct","Nov","Dec");
where the minus one removes the "dummy" required items.
David
>Replace Count(QryComplaintSummary.RecordID)
with
Nz(Count(QryComplaintSummary.RecordID),0)
How embarrassing. This is the first thing I tried but through years of
sloppy programming I used Nz without the second argument. I see in the
help file that the second argument is "Optional (unless used in a
query)"
So I have learned something as well!! This discussion thread is closed Replies have been disabled for this discussion. Similar topics
9 posts
views
Thread by Doug Ly |
last post: by
|
2 posts
views
Thread by Tony |
last post: by
|
5 posts
views
Thread by Randy Harris |
last post: by
|
1 post
views
Thread by Bill Nguyen |
last post: by
|
2 posts
views
Thread by pmarisole |
last post: by
| | | | | | | | | | | | | | |