Skip to Main Content

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Paul .

Asked: August 02, 2021 - 5:42 pm UTC

Last updated: August 03, 2021 - 10:42 am UTC

Version: 19c

Viewed 1000+ times

You Asked

I have the following test CASE (see below), which works fine. I want all the information to be displayed as is. The issue is I only want to group by access_date, employee_id. When I remove the first grouping set I get the error 'Invalid group by'. Is there any way to get around this issue?

ALTER SESSION SET 
 NLS_DATE_FORMAT = 'MMDDYYYY HH24:MI:SS';

CREATE OR REPLACE TYPE nt_date IS TABLE OF DATE;
/
CREATE OR REPLACE FUNCTION generate_dates_pipelined(
  p_from IN DATE,
  p_to   IN DATE
)
RETURN nt_date  PIPELINED   DETERMINISTIC
IS
  v_start DATE := TRUNC(LEAST(p_from, p_to));
  v_end   DATE := TRUNC(GREATEST(p_from, p_to));
BEGIN
 LOOP
    PIPE ROW (v_start);
    EXIT WHEN v_start >= v_end;
    v_start := v_start + INTERVAL '1' DAY;
  END LOOP;
  RETURN;
END generate_dates_pipelined;
/

create table employees(
  employee_id NUMBER(6), 
  first_name VARCHAR2(20),
  last_name VARCHAR2(20),
  card_num VARCHAR2(10),
  work_days VARCHAR2(7)
);

ALTER TABLE employees
ADD (
  CONSTRAINT employees_pk PRIMARY KEY (employee_id)
      );

INSERT INTO employees (
  EMPLOYEE_ID,
  first_name, 
  last_name,
  card_num,
  work_days
)
WITH names AS ( 
  SELECT 1, 'Jane',     'Doe',      'F123456', 'NYYYYYN'   FROM dual UNION ALL 
  SELECT 2, 'Madison', 'Smith', 'R33432','NYYYYYN' FROM dual UNION ALL 
  SELECT 3, 'Justin',   'Case',     'C765341','NYYYYYN' FROM dual UNION ALL 
  SELECT 4, 'Mike',     'Jones',      'D564311','NYYYYYN' FROM dual  )
SELECT * FROM names;  

CREATE TABLE locations AS
   SELECT level AS location_id,
          'Door ' || level AS location_name,
          CASE round(dbms_random.value(1,3)) 
              WHEN 1 THEN 'T' 
              WHEN 2 THEN 'T' 
              WHEN 3 THEN 'T' 
          END AS location_type
  FROM   dual
  CONNECT BY level <= 3;


ALTER TABLE locations 
   ADD ( CONSTRAINT locations_pk
   PRIMARY KEY (location_id));

create table access_history(     
   seq_num integer  GENERATED BY DEFAULT AS IDENTITY (START WITH 1) NOT NULL,
   employee_id NUMBER(6), 
   card_num varchar2(10),
   location_id number(4),
   access_date date,
   processed NUMBER(1) default 0
);


create or replace procedure create_access_history(p_start_date date, p_end_date date)
IS
BEGIN
  INSERT into  access_history
     (
      employee_id,
      card_num,
       location_id, 
       access_date
     )
  WITH  cntr  AS
    (
  SELECT LEVEL - 1 AS n
  FROM     dual
  CONNECT BY LEVEL <= 15 -- Max number of rows per employee per date
  )
    , got_location_num  AS
  (
  SELECT  location_id
  ,    ROW_NUMBER () OVER (ORDER BY location_id) AS location_num
  ,    COUNT (*)   OVER ()            AS max_location_num
  FROM     locations
  )
  ,    employee_days  AS
  (
  SELECT     e.employee_id, e.card_num
  ,      d.column_value         AS access_date
  ,          dbms_random.value (0, 15) AS rn    -- 0 to max number of rows per employee per date
  FROM     employees e
  CROSS JOIN TABLE (generate_dates_pipelined (p_start_date, p_end_date)) d
  )
   ,        employee_n_days  AS
  (
  SELECT     ed.employee_id, ed.card_num, ed.access_date
  ,     dbms_random.value (0, 1) AS lrn
  FROM     employee_days        ed
  JOIN    cntr            c  ON  c.n <= ed.rn
  )
    SELECT    n.employee_id,       n.card_num, l.location_id,  n.access_date + 
    NUMTODSINTERVAL(FLOOR(DBMS_RANDOM.VALUE(0,86399)), 'SECOND') 
    FROM     employee_n_days  n
    JOIN     got_location_num  l  ON l.location_num = CEIL (n.lrn * l.max_location_num); 
END;
/

EXEC  create_access_history (SYSDATE,  SYSDATE+3);

select TRUNC(a. access_date) access_date,
       e.employee_id, 
       e.first_name,
       e.last_name,
       e.card_num,
       l.location_id,
       l.location_name,
       count(*) cnt         
FROM  employees    e
JOIN  access_history a ON a.employee_id = e.employee_id
JOIN  locations     l ON l.location_id = a.location_id
GROUP BY  GROUPING SETS (
  (TRUNC(a.access_date),
     e.employee_id, 
     e.first_name,
     e.last_name,
     e.card_num,
     l.location_id,
   l.location_name),
  (TRUNC(a.access_date), e.employee_id),       
  (trunc(a.access_date)),
  ()
)
ORDER BY trunc(a. access_date),e.employee_id,l.location_id;

and Chris said...

You mean you're getting an ORA-979 when doing this?

select TRUNC(a. access_date) access_date,
       e.employee_id, 
       e.first_name,
       e.last_name,
       e.card_num,
       l.location_id,
       l.location_name,
       count(*) cnt         
FROM  employees    e
JOIN  access_history a ON a.employee_id = e.employee_id
JOIN  locations     l ON l.location_id = a.location_id
GROUP BY  GROUPING SETS (
  (TRUNC(a.access_date), e.employee_id),       
  (trunc(a.access_date)),
  ()
)
ORDER BY trunc(a. access_date),e.employee_id,l.location_id;

ORA-00979: not a GROUP BY expression


If so the issue is that all unaggregated columns in the select list (and order by) must also be in your group by.

So either you need to remove these columns from the select & order by or include them in your group by, for example:

select TRUNC(a. access_date) access_date,
       e.employee_id, 
       count(*) cnt         
FROM  employees    e
JOIN  access_history a ON a.employee_id = e.employee_id
JOIN  locations     l ON l.location_id = a.location_id
GROUP BY  GROUPING SETS (
  (TRUNC(a.access_date), e.employee_id),       
  (trunc(a.access_date)),
  ()
)
ORDER BY trunc(a. access_date),e.employee_id;

ACCESS_DATE             EMPLOYEE_ID    CNT   
08032021 00:00:00                 1      4 
08032021 00:00:00                 2      6 
08032021 00:00:00                 3      8 
08032021 00:00:00                 4      9 
08032021 00:00:00            <null>     27 
08042021 00:00:00                 1      5 
08042021 00:00:00                 2      9 
...


If you want to include these columns in the output, but "don't care" what values they have, from 21c you can use the any_value function:

select TRUNC(a. access_date) access_date,
       e.employee_id,
       any_value ( e.first_name ),
       any_value ( e.last_name ),
       any_value ( e.card_num ),
       any_value ( l.location_id ),
       any_value ( l.location_name ),
       count(*) cnt         
FROM  employees    e
JOIN  access_history a ON a.employee_id = e.employee_id
JOIN  locations     l ON l.location_id = a.location_id
GROUP BY  GROUPING SETS (
  (TRUNC(a.access_date), e.employee_id),       
  (trunc(a.access_date)),
  ()
)
ORDER BY trunc(a. access_date),e.employee_id;

ACCESS_DATE         EMPLOYEE_ID ANY_VALUE(E.FIRST_NAME)   ANY_VALUE(E.LAST_NAME)   ANY_VALUE(E.CARD_NUM)   ANY_VALUE(L.LOCATION_ID) ANY_VALUE(L.LOCATION_NAME)  CNT   
08032021 00:00:00             1 Jane                      Doe                      F123456                                        1 Door 1                        3 
08032021 00:00:00             2 Madison                   Smith                    R33432                                         1 Door 1                        4 
08032021 00:00:00             3 Justin                    Case                     C765341                                        1 Door 1                        5 
08032021 00:00:00             4 Mike                      Jones                    D564311                                        1 Door 1                       11 
08032021 00:00:00        <null> Madison                   Smith                    R33432                                         1 Door 1                       23 
08042021 00:00:00             1 Jane                      Doe                      F123456                                        1 Door 1                        9 
08042021 00:00:00             2 Madison                   Smith                    R33432                                         1 Door 1                        7 
...


Is this answer out of date? If it is, please let us know via a Comment

More to Explore

Analytics

Analytic SQL got you confused? Check out Connor McDonald's complete video course.