Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: SQL Question - Sum with group by
This message is in MIME format. Since your mail reader does not understand
this format, some or all of this message may not be legible.
------_=_NextPart_001_01BFF5A4.262B53A0
Content-Type: text/plain;
charset="iso-8859-1"
Concatenate all columns which you want the group by. In the final result, you do a substr to separate data:
> select i.sku||to_char(o.order_date,'YYYYMM') as group_result,
> sum(i.quantity) as qty
> from items i,
> orders o
> where i.order_id = o.order_id
> and ( o.status=5
> or o.status=7
> or ( o.status=16 and i.printed=1 )
> )
> and ( o.store_id = 'V' )
> group by i.sku||to_char(o.order_date,'YYYYMM');
>
>
Washington Oliveira
woliveira_at_americel.com.br
> ----------
> De: Thomas L. Harleman[SMTP: ]
> Responder: ORACLE-L_at_fatcity.com
> Enviada: Segunda-feira, 24 de Julho de 2000 16:10
> Para: Multiple recipients of list ORACLE-L
> Assunto: RE: SQL Question - Sum with group by
>
>
>
> Tom Harleman
> 11080 Willowmere Dr.
> Indianapolis, IN 46280
> 317-844-2884 Home
> 317-843-9122 Home Office
>
>
> -----Original Message-----
> DeMeester
> Sent: Thursday, July 20, 2000 9:54 PM
> To: Multiple recipients of list ORACLE-L
> Yes, I've done this a lot. GROUP BY the same column defs as in the SELECT.
> I
> usually format my code like this so I can cut and paste the SELECT columns
> into the GROUP BY clause:
>
> select i.sku,
> to_char(o.order_date, 'MM') as month,
> to_char(o.order_date,'YYYY') as year,
> sum(i.quantity) as qty
> from items i,
> orders o
> where i.order_id = o.order_id
> and ( o.status=5
> or o.status=7
> or ( o.status=16 and i.printed=1 )
> )
> and ( o.store_id = 'V' )
> group by i.sku,
> to_char(o.order_date, 'MM'),
> to_char(o.order_date,'YYYY');
>
>
> ==========================================================================
> ==
> I have trouble to create a view that will sum a quantity field from a
> joined
> table by sku and year and month (YYYYMM). But also display the sku,
> summed
> quantity, MM, and YYYY. The ouput of the view is going to write to an
> inventory table. Sample output: VA013000, 05, 2000, 50 One record per
> each YYYYMM for each sku.)
>
> If I use the following script, it generates detail quantity for each sku.
> The quantity is not summaried by the YYYYMM. If I use group by i.sku,
> to_char(o.order_date,'YYYYMM') then I got error.
>
> create or replace view month_qty_sum_by_sku as
> select i.sku, to_char(o.order_date, 'MM') as month, to_char(o.order_date,
> 'YYYY') as year
> ,sum(i.quantity) as qty
> from items i, orders o where
> i.order_id = o.order_id and (o.status=5 or o.status=7 or (o.status=16 and
> i.printed=1)) and
> (o.store_id = 'V')
> group by i.sku, o.order_date;
>
> I did try to define a new yymm column and try to group by sku and yymm
> column and it did not work.
>
> Any one has done this sort of SQL?
>
>
> TIA
> Regards,
> Lucia
>
> --
> Author: Lucia DeMeester
> INET: ldemeester_at_nm2.com
>
> Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051
> San Diego, California -- Public Internet access / Mailing Lists
> --------------------------------------------------------------------
> To REMOVE yourself from this mailing list, send an E-Mail message
> to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
> the message BODY, include a line containing: UNSUB ORACLE-L
> (or the name of mailing list you want to be removed from). You may
> also send the HELP command for other information (like subscribing).
>
> --
> Author: Thomas L. Harleman
> INET: tharleman_at_iquest.net
>
> Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051
> San Diego, California -- Public Internet access / Mailing Lists
> --------------------------------------------------------------------
> To REMOVE yourself from this mailing list, send an E-Mail message
> to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
> the message BODY, include a line containing: UNSUB ORACLE-L
> (or the name of mailing list you want to be removed from). You may
> also send the HELP command for other information (like subscribing).
>
------_=_NextPart_001_01BFF5A4.262B53A0
Content-Type: text/html;
charset="iso-8859-1"
Content-Transfer-Encoding: quoted-printable
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 3.2//EN"> <HTML> <HEAD> <META HTTP-EQUIV=3D"Content-Type" CONTENT=3D"text/html; =charset=3Dus-ascii">
<TITLE>RE: SQL Question - Sum with group by</TITLE> </HEAD> <BODY>
<P><FONT COLOR=3D"#0000FF" SIZE=3D2 FACE=3D"Arial">Concatenate all =
columns which you want the group by. In the final result, you do a =
substr to separate data:</FONT>
</P>
<P><FONT SIZE=3D2 FACE=3D"Arial">select i.sku</FONT><FONT = COLOR=3D"#0000FF" SIZE=3D2 FACE=3D"Arial">||</FONT><FONT SIZE=3D2 =
FACE=3D"Arial">to_char(o.order_date,'YYYY</FONT><FONT COLOR=3D"#0000FF" = SIZE=3D2 FACE=3D"Arial">MM</FONT><FONT SIZE=3D2 = FACE=3D"Arial">')</FONT><FONT COLOR=3D"#0000FF" SIZE=3D2 = FACE=3D"Arial"> as group_result,</FONT>
FACE=3D"Arial">to_char(o.order_date,'YYYY</FONT><FONT COLOR=3D"#0000FF" = SIZE=3D2 FACE=3D"Arial">MM</FONT><FONT SIZE=3D2 = FACE=3D"Arial">')</FONT><FONT COLOR=3D"#0000FF" SIZE=3D2 = FACE=3D"Arial">;</FONT>
<P><FONT COLOR=3D"#0000FF" SIZE=3D2 FACE=3D"Arial">Washington =
Oliveira</FONT>
<BR><FONT COLOR=3D"#0000FF" SIZE=3D2 =
FACE=3D"Arial">woliveira_at_americel.com.br</FONT>
</P>
<BR>
<P><FONT SIZE=3D2 FACE=3D"MS Sans Serif">----------</FONT>
<BR><B><FONT SIZE=3D2 FACE=3D"MS Sans Serif">De:</FONT></B> =
<FONT SIZE=3D2 FACE=3D"MS Sans Serif">Thomas L. =
Harleman[SMTP:</FONT> <FONT =
SIZE=3D2 FACE=3D"MS Sans Serif">]</FONT>
<BR><B><FONT SIZE=3D2 FACE=3D"MS Sans Serif">Responder:</FONT></B> =
<FONT SIZE=3D2 FACE=3D"MS Sans =
Serif">ORACLE-L_at_fatcity.com</FONT>
<BR><B><FONT SIZE=3D2 FACE=3D"MS Sans Serif">Enviada:</FONT></B> =
<FONT SIZE=3D2 FACE=3D"MS Sans =
Serif">Segunda-feira, 24 de Julho de 2000 16:10</FONT>
<BR><B><FONT SIZE=3D2 FACE=3D"MS Sans Serif">Para:</FONT></B> =
<FONT SIZE=3D2 FACE=3D"MS Sans Serif">Multiple recipients of list =
ORACLE-L</FONT>
<BR><B><FONT SIZE=3D2 FACE=3D"MS Sans Serif">Assunto:</FONT></B> =
<FONT SIZE=3D2 FACE=3D"MS Sans =
Serif">RE: SQL Question - Sum with group by</FONT>
</P> <BR> <BR> <P><FONT SIZE=3D2 FACE=3D"Arial">Tom Harleman</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">11080 Willowmere Dr.</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">Indianapolis, IN 46280</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">317-844-2884 Home</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">317-843-9122 Home Office</FONT></P>
<P><FONT SIZE=3D2 FACE=3D"Arial">-----Original Message-----</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">DeMeester</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">Sent: Thursday, July 20, 2000 9:54 =PM</FONT>
<P><FONT SIZE=3D2 FACE=3D"Arial">select i.sku,</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial"> =
to_char(o.order_date, 'MM') as month,</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial"> =
to_char(o.order_date,'YYYY') as year,</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial"> =
sum(i.quantity) as qty</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">from items i,</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial"> =
orders o</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">where i.order_id =3D =
o.order_id</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">and ( =
o.status=3D5</FONT>
<BR><FONT SIZE=3D2 =
FACE=3D"Arial"> or =
o.status=3D7</FONT>
<BR><FONT SIZE=3D2 =
FACE=3D"Arial"> or ( =
o.status=3D16 and i.printed=3D1 )</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial"> =
)</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">and ( o.store_id =
=3D 'V' )</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">group by i.sku,</FONT>
<BR><FONT SIZE=3D2 =
FACE=3D"Arial"> =
to_char(o.order_date, 'MM'),</FONT>
<BR><FONT SIZE=3D2 =
FACE=3D"Arial"> =
to_char(o.order_date,'YYYY');</FONT>
</P>
<BR>
<P><FONT SIZE=3D2 = FACE=3D"Arial">=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D= =3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D= =3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D=3D= =3D=3D=3D=3D=3D=3D=3D=3D=3D</FONT>
<P><FONT SIZE=3D2 FACE=3D"Arial">If I use the following script, it =
generates detail quantity for each sku.</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">The quantity is not summaried by the =
YYYYMM. If I use group by i.sku,</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">to_char(o.order_date,'YYYYMM') then I =
got error.</FONT>
</P>
<P><FONT SIZE=3D2 FACE=3D"Arial">create or replace view =
month_qty_sum_by_sku as</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">select i.sku, to_char(o.order_date, =
'MM') as month, to_char(o.order_date,</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">'YYYY') as year</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">,sum(i.quantity) as qty</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">from items i, orders o where</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">i.order_id =3D o.order_id and =(o.status=3D5 or o.status=3D7 or (o.status=3D16 and</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">i.printed=3D1)) and</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial"> (o.store_id =3D 'V')</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">group by i.sku, o.order_date;</FONT> </P>
<P><FONT SIZE=3D2 FACE=3D"Arial">I did try to define a new yymm column =
and try to group by sku and yymm</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">column and it did not work.</FONT>
</P>
<P><FONT SIZE=3D2 FACE=3D"Arial">Any one has done this sort of =
SQL?</FONT>
</P>
<BR>
<P><FONT SIZE=3D2 FACE=3D"Arial">TIA</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">Regards,</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">Lucia</FONT> </P> <P><FONT SIZE=3D2 FACE=3D"Arial">--</FONT><BR><FONT SIZE=3D2 FACE=3D"Arial">Author: Lucia DeMeester</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial"> INET: = ldemeester_at_nm2.com</FONT>
<P><FONT SIZE=3D2 FACE=3D"Arial">Fat City Network =
Services -- (858) 538-5051 FAX: (858) =
538-5051</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">San Diego, =
California -- Public Internet =
access / Mailing Lists</FONT>
<BR><FONT SIZE=3D2 =
FACE=3D"Arial">---------------------------------------------------------=-----------</FONT>
<P><FONT SIZE=3D2 FACE=3D"Arial">-- </FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial">Author: Thomas L. Harleman</FONT> <BR><FONT SIZE=3D2 FACE=3D"Arial"> INET: =tharleman_at_iquest.net</FONT>
<P><FONT SIZE=3D2 FACE=3D"Arial">Fat City Network =
Services -- (858) 538-5051 FAX: (858) =
538-5051</FONT>
<BR><FONT SIZE=3D2 FACE=3D"Arial">San Diego, =
California -- Public Internet =
access / Mailing Lists</FONT>
<BR><FONT SIZE=3D2 =
FACE=3D"Arial">---------------------------------------------------------=-----------</FONT>