Hi Frank,
On 2/22/2013 10:55 AM, fbocch2595@xxxxxxx wrote:
Hi Folks, this statement runs fine;
SELECT LGSESN, LGDATE FROM anloga
WHERE LGSESN NOT LIKE '%ARCHIVE%'
order by LGSESN
but if I want to only have each LGSESN output a single line with the total number of hits for all the LGSESN's, what's the syntax for that?
There are two things going on to satisfy your request. The first is to
generate the equivalent of RPG's L1 on LGSESN. SQL does that with GROUP
BY. There's a catch though - everything in the SELECT clause needs to be:
a) in the GROUP BY clause -or-
b) an aggregate function like SUM(votes)
So:
SELECT LGSESN, LGDATE FROM anloga
WHERE LGSESN NOT LIKE '%ARCHIVE%'
group by LGSESN, LGDATE
order by LGSESN
The key concept here is that everything in each returned row is a total
line. You can't mix detail and total on the same line. In that spirit,
you also can't mix L1 and LR on the same line, so to satisfy the second
half (total up the LGSESN's) you need a separate SELECT:
SELECT count(*) FROM anloga
WHERE LGSESN NOT LIKE '%ARCHIVE%'
Not exactly like a query, or an RPG LR. But SQL allows us to combine
separate SELECTS into one result set via UNION. The caveat is that each
SELECT in the UNION must have the same columns. Well, the same number
and type, but you get the idea. Because the top query is selecting
LGSESN and LGDATE, the bottom query needs the same two columns, but
COUNT(*) isn't really either one. So to make the two SELECTs
compatible, I'd add a count to the top and two dummy columns to the bottom:
SELECT LGSESN, LGDATE, count(*) FROM anloga
WHERE LGSESN NOT LIKE '%ARCHIVE%'
group by LGSESN, LGDATE
UNION
SELECT '99999', 0, count(*) FROM anloga
WHERE LGSESN NOT LIKE '%ARCHIVE%'
order by 1
The trick with the UNION is the ORDER BY. Since there are multiple
SELECTs being lumped together, the column names aren't valid for the
sort. Use the column numbers instead.
Is there any tip sheets or manuals for learning SQL?
I rather like Graeme Birchall's cookbook:
http://mysite.verizon.net/Graeme_Birchall/id1.html It's not specific to
DB2 for i, but I have learnt quite a lot from it.
--buck
As an Amazon Associate we earn from qualifying purchases.