Mohamed Houri’s Oracle Notes

March 21, 2012

ORA-00979: not a GROUP BY expression

Filed under: PL/SQL — hourim @ 4:17 pm

Yesterday I found something interesting about the GROUP BY clause. The model (borrowed from Jonathan Lewis as always) is

mhouri.world> create table t1
  2  as
  3  with generator as (
  4      select  --+ materialize
  5          rownum id
  6      from dual
  7      connect by
  8          level <= 10000)
  9  select
 10      rownum                  id,
 11      trunc(dbms_random.value(1,1000))    n1,
 12      lpad(rownum,10,'0') vc2,
 13      rpad('x',100)       vc3
 14  from
 15      generator   v1,
 16      generator   v2
 17  where
 18      rownum <= 1000000;

Table created.

mhouri.world> create index t1_n1 on t1(id, n1);
Index created.

mhouri.world> create table t2
  2  as
  3  with generator as (
  4      select  --+ materialize
  5          rownum id
  6      from dual
  7      connect by
  8          level <= 10000)
  9  select
 10      rownum                  id,
 11      trunc(dbms_random.value(10001,20001))   x1,
 12      lpad(rownum,10,'0') vc2,
 13      rpad('x',100)       vc3
 14  from
 15      generator   v1,
 16      generator   v2
 17  where
 18      rownum <= 1000000;

Table created.

mhouri.world> create index t2_i1 on t2(x1);

Index created.

mhouri.world> exec dbms_stats.gather_table_stats(user, 't2', method_opt => 'FOR ALL COLUMNS SIZE 1');

PL/SQL procedure successfully completed.

mhouri.world> exec dbms_stats.gather_table_stats(user, 't1', method_opt => 'FOR ALL COLUMNS SIZE 1');

PL/SQL procedure successfully completed.

mhouri.world> select
  2       t1.id
  3      ,sum(t1.n1)
  4      ,(sum(t1.n1) +
  5             (select
  6                   sum(t2.x1) x
  7              from  t2
  8              where t2.id  = t1.id
  9              and   t2.x1  = t1.n1
 10              )
 11        ) as alias1
 12  from   t1
 13   where t1.id   = 11
 14   and   t1.n1   = 707
 15   group by
 16         t1.id
 17        ;
            and   t2.x1  = t1.n1
                           *
ERROR at line 9:
ORA-00979: not a GROUP BY expression 

Why do I need to group by t1.n1 also?

mhouri.world> select
  2       t1.id
  3      ,sum(t1.n1)
  4      ,(sum(t1.n1) +
  5             (select
  6                   sum(t2.x1) x
  7              from  t2
  8              where t2.id  = t1.id
  9              and   t2.x1  = t1.n1
 10              )
 11        ) as alias1
 12  from   t1
 13   where t1.id   = 11
 14   and   t1.n1   = 707
 15   group by
 16         t1.id
 17        ,t1.n1
 18        ;

        ID SUM(T1.N1)     ALIAS1                                                
---------- ---------- ----------                                                
        11        707                                                           

If I slightly change the above query by adding an extra where clause in the sub select (and t2.vc2 = t1.vc2)

mhouri.world> select
  2       t1.id
  3      ,sum(t1.n1)
  4      ,(sum(t1.n1) +
  5             (select
  6                   sum(t2.x1) x
  7              from  t2
  8              where t2.id  = t1.id
  9              and   t2.x1  = t1.n1
 10              and   t2.vc2 = t1.vc2
 11              )
 12        ) as alias1
 13  from   t1
 14   where t1.id   = 11
 15   and   t1.n1   = 707
 16   group by
 17         t1.id
 18        ,t1.n1
 19        ;
            and   t2.vc2 = t1.vc2
                           *
ERROR at line 10:
ORA-00979: not a GROUP BY expression 

The same error is raised again meaning that I need to group by this extra column (vc2) added into the where clause


mhouri.world> select
  2       t1.id
  3      ,sum(t1.n1)
  4      ,(sum(t1.n1) +
  5             (select
  6                   sum(t2.x1) x
  7              from  t2
  8              where t2.id  = t1.id
  9              and   t2.x1  = t1.n1
 10              and   t2.vc2 = t1.vc2
 11              )
 12        ) as alias1
 13  from   t1
 14   where t1.id   = 11
 15   and   t1.n1   = 707
 16   group by
 17         t1.id
 18        ,t1.n1
 19        ,t1.vc2
 20        ;

        ID SUM(T1.N1)     ALIAS1                                                
---------- ---------- ----------                                                
        11        707                                                           

And so on. Each time a column from table t1 (other than id1) is added to the sub select we need to group by that column

Any explanation?

May be when observing the execution plan


mhouri.world> select * from table(dbms_xplan.display_cursor);

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------

SQL_ID  5mzq0bmusjvtg, child number 0
-------------------------------------
select      t1.id     ,sum(t1.n1)     ,(sum(t1.n1) +            (select
           sum(t2.x1) x             from  t2             where t2.id  = t1.id
            and   t2.x1  = t1.n1             )       ) as alias1 from   t1
where t1.id   = 11  and   t1.n1   = 707  group by        t1.id       ,t1.n1

Plan hash value: 508850092

--------------------------------------------------------------------------------------
| Id  | Operation                    | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |       |       |       |     3 (100)|          |
|   1 |  SORT AGGREGATE              |       |     1 |    10 |            |          |
|*  2 |   TABLE ACCESS BY INDEX ROWID| T2    |     1 |    10 |   103   (0)| 00:00:01 |
|*  3 |    INDEX RANGE SCAN          | T2_I1 |   100 |       |     3   (0)| 00:00:01 |
|   4 |  SORT GROUP BY NOSORT        |       |     1 |     9 |     3   (0)| 00:00:01 |
|*  5 |   INDEX RANGE SCAN           | T1_N1 |     1 |     9 |     3   (0)| 00:00:01 |
--------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("T2"."ID"=:B1)
   3 - access("T2"."X1"=:B1)
   5 - access("T1"."ID"=11 AND "T1"."N1"=707)
                                                                                

…..

Leave a Comment »

No comments yet.

RSS feed for comments on this post. TrackBack URI

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

Blog at WordPress.com.

Tony's Oracle Tips

Tony Hasler's light hearted approach to learning about Oracle

Richard Foote's Oracle Blog

Focusing Specifically On Oracle Indexes, Database Administration and Some Great Music

Hatem Mahmoud Oracle's blog

Just another Oracle blog : Database topics and techniques

Mohamed Houri’s Oracle Notes

Qui se conçoit bien s’énonce clairement

Oracle Diagnostician

Performance troubleshooting as exact science

Raheel's Blog

Things I have learnt as Oracle DBA

Coskan's Approach to Oracle

What I learned about Oracle

So Many Oracle Manuals, So Little Time

“Books to the ceiling, Books to the sky, My pile of books is a mile high. How I love them! How I need them! I'll have a long beard by the time I read them”—Lobel, Arnold. Whiskers and Rhymes. William Morrow & Co, 1988.

EU Careers info

Your career in the European Union

Carlos Sierra's Tools and Tips

Tools and Tips for Oracle Performance and SQL Tuning

Oracle Scratchpad

Just another Oracle weblog

OraStory

Dominic Brooks on Oracle Performance, Tuning, Data Quality & Sensible Design ... (Now with added Sets Appeal)

%d bloggers like this: