SELECT Warnicke03.[Stream Name], Warnicke03.[Month/Day],
Min(Warnicke03.Celsius) AS Minimum, Max(Warnicke03.Celsius) AS Maximum,
Avg(Warnicke03.Celsius) AS Average
, Abs(Sum(Warnicke03.Celsius<=13)) AS [Hours <13]
, Abs(Sum((Warnicke03.Celsius >13 and Celsius <=18)) AS [Hours Between 13
and 18]
, Abs(Sum(Warnicke03.Celsius >18)) AS [Hours Greater Than 18]
FROM Warnicke03
GROUP BY Warnicke03.[Stream Name], Warnicke03.[Month/Day];
Celsius <= 13 returns either 0 or -1 (False or True)
Sum totals the values returned
Abs removes the minus sign
Another way of doing this is to use
Count(IIF(Celsius<=13,1,Null))
Since the count function counts all non-null values.
SELECT Warnicke03.[Stream Name], Warnicke03.[Month/Day],
Min(Warnicke03.Celsius) AS Minimum, Max(Warnicke03.Celsius) AS Maximum,
Avg(Warnicke03.Celsius) AS Average
, Count(IIF(Celsius<=13,1,Null)) AS [Hours <13]
, Count(IIF(Celsius >13 and Celsius <=18,1,Null)) AS [Hours Between 13 and
18]
, Count(IIF(Celsius >18,1,Null)) AS [Hours Greater Than 18]
FROM Warnicke03
GROUP BY Warnicke03.[Stream Name], Warnicke03.[Month/Day];
Otyokwa said:
SELECT Warnicke03.[Stream Name], Warnicke03.[Month/Day],
Min(Warnicke03.Celsius) AS Minimum, Max(Warnicke03.Celsius) AS Maximum,
Avg(Warnicke03.Celsius) AS Average, Count(Warnicke03.Celsius) AS [Hours
<13],
Count(Warnicke03.Celsius) AS [Hours Between 13 and 18],
Count(Warnicke03.Celsius) AS [Hours Greater Than 18]
FROM Warnicke03
WHERE (((Warnicke03.Celsius)<=13) AND ((Warnicke03.Celsius)>13 And
(Warnicke03.Celsius)<18) AND ((Warnicke03.Celsius)>18))
GROUP BY Warnicke03.[Stream Name], Warnicke03.[Month/Day];
I can get the min, max and ave to run and can get each hour count to run
separately, but they won't show a 0 where there is no data.
John Spencer said:
Dear Otyokwa,
Please copy and post the SQL of your query that is working. I will try
to
modify it for you.
(Possibly unneeded instructions follow)
Open the query
Select View:Sql from the Menu
Select all the text
Copy it
Paste it into the message