This site is currently read-only as we are migrating to Oracle Forums for an improved community experience. You will not be able to initiate activity until January 30th, when you will be able to use this site as normal.

    Forum Stats

  • 3,889,901 Users
  • 2,269,775 Discussions
  • 7,916,823 Comments

Discussions

Sorting by a specific column, but not include that on Grouping

User_QDHXF
User_QDHXF Member Posts: 27 Green Ribbon

Hello,

Create TABLE T1_TEMP(RO_TYPE VARCHAR2(30), Jurisdiction Varchar2(10), Reopening_Order NUMBER, RO_Pending NUMBER, RO_Waiting NUMBER, RO_Granted NUMBER);

Insert into T1_TEMP VALUES ('Provider Requested','J5',1,0,0,1);

Insert into T1_TEMP VALUES ('Appeal','J5',2,1,0,1);

Insert into T1_TEMP VALUES ('Contractor Initiated','J5',3,1,2,3);

Insert into T1_TEMP VALUES ('Home Initiated','J5',8,1,2,3);

Insert into T1_TEMP VALUES ('Govt Request','J5',11,1,2,3);

Insert into T1_TEMP VALUES ('State Initiated','J5',4,1,2,3);

When I query against the above table, I have:

I am trying to get the numbers summed by each column, grouped by only Juridisction and sort the data based on Reopening_Order. The expected result is shown below:

The grouping must not have Reopening_Order. I tried a few methods, but didn't get the expected result.

Any help is greatly appreciated. Thank you!!

Tagged:

Best Answer

  • mathguy
    mathguy Member Posts: 11,041 Black Diamond
    Answer ✓

    What you show as the desired result is called GROUP BY ROLLUP. It can also be achieved with GROUP BY GROUPING SETS as Mr. Kulash demonstrated, but that is overkill.

    In your inputs you have two columns, REOPENING_ORDER and RO_TYPE. You didn't explain what they are, how they are related, etc. Mr. Kulash assumed the sub-groups (in your example, just individual rows) are by RO_TYPE. Since you want the results ordered by REOPENING_ORDER, that would only make sense if all reopening orders had different types, which doesn't make a lot of sense. You seem to want the output to be the same as the input, plus the total row (and proper ordering); I assume REOPENING_ORDER is primary key here, and RO_TYPE may have duplicates even for a single jurisdiction (in the real-life data; it doesn't in the test data you posted). So, the grouping by rollup should be by REOPENING_ORDER, rather than by RO_TYPE.

    So:

    select case grouping(reopening_order) when 0 then min(ro_type)
                                                 else 'Total' end as ro_type,
           jurisdiction, reopening_order, sum(ro_pending) as ro_pending,
           sum(ro_waiting) as ro_waiting, sum(ro_granted) as ro_granted
    from   t1_temp
    group  by jurisdiction, rollup(reopening_order)
    order  by reopening_order                        -- see below!
    ;
    
    RO_TYPE                        JURISDICTION REOPENING_ORDER RO_PENDING RO_WAITING RO_GRANTED
    ------------------------------ ------------ --------------- ---------- ---------- ----------
    Provider Requested             J5                         1          0          0          1
    Appeal                         J5                         2          1          0          1
    Contractor Initiated           J5                         3          1          2          3
    State Initiated                J5                         4          1          2          3
    Home Initiated                 J5                         8          1          2          3
    Govt Request                   J5                        11          1          2          3
    Total                          J5                                    5          8         14
    


    If there is more than one jurisdiction (as there probably is), you likely want to

    order by jurisdiction, reopening_order
    

    instead of ordering by REOPENING_ORDER alone.

Answers

  • Frank Kulash
    Frank Kulash Boston, USAMember, Moderator Posts: 43,002 Red Diamond

    Hi, @User_QDHXF

    Thanks for posting the CREATE TABLE and INSERT statements; that's very helpful!

    The grouping must not have Reopening_Order.

    Why not? What's wrong with this:

    SELECT    CASE
    	      WHEN  GROUPING (ro_type) = 0
    	      THEN  ro_type
    	      ELSE  '  Total'
    	  END			AS ro_type
    , 	  jurisdiction
    ,	  reopening_order
    ,	  SUM (ro_pending)	AS ro_pending
    ,	  SUM (ro_waiting)	AS ro_waiting
    ,	  SUM (ro_granted)	AS ro_granted
    FROM	  t1_temp
    GROUP BY  GROUPING SETS ( (ro_type, jurisdiction, reopening_order)
          	  		, (         jurisdiction                 )
    			)
    ORDER BY  reopening_order
    ;
    

    ? Output:

    RO_TYPE                        JURISDICTION REOPENING_ORDER RO_PENDING RO_WAITING RO_GRANTED
    ------------------------------ ------------ --------------- ---------- ---------- ----------
    Provider Requested             J5                         1          0          0          1
    Appeal                         J5                         2          1          0          1
    Contractor Initiated           J5                         3          1          2          3
    State Initiated                J5                         4          1          2          3
    Home Initiated                 J5                         8          1          2          3
    Govt Request                   J5                        11          1          2          3
      Total                        J5                                    5          8         14
    

    If you really, really don't want to include reopening_order in the GROUP BY clause, then you could use a CASE expression, like the one for ro_type, above, but it won't be any faster or simpler.

    User_QDHXF
  • mathguy
    mathguy Member Posts: 11,041 Black Diamond
    Answer ✓

    What you show as the desired result is called GROUP BY ROLLUP. It can also be achieved with GROUP BY GROUPING SETS as Mr. Kulash demonstrated, but that is overkill.

    In your inputs you have two columns, REOPENING_ORDER and RO_TYPE. You didn't explain what they are, how they are related, etc. Mr. Kulash assumed the sub-groups (in your example, just individual rows) are by RO_TYPE. Since you want the results ordered by REOPENING_ORDER, that would only make sense if all reopening orders had different types, which doesn't make a lot of sense. You seem to want the output to be the same as the input, plus the total row (and proper ordering); I assume REOPENING_ORDER is primary key here, and RO_TYPE may have duplicates even for a single jurisdiction (in the real-life data; it doesn't in the test data you posted). So, the grouping by rollup should be by REOPENING_ORDER, rather than by RO_TYPE.

    So:

    select case grouping(reopening_order) when 0 then min(ro_type)
                                                 else 'Total' end as ro_type,
           jurisdiction, reopening_order, sum(ro_pending) as ro_pending,
           sum(ro_waiting) as ro_waiting, sum(ro_granted) as ro_granted
    from   t1_temp
    group  by jurisdiction, rollup(reopening_order)
    order  by reopening_order                        -- see below!
    ;
    
    RO_TYPE                        JURISDICTION REOPENING_ORDER RO_PENDING RO_WAITING RO_GRANTED
    ------------------------------ ------------ --------------- ---------- ---------- ----------
    Provider Requested             J5                         1          0          0          1
    Appeal                         J5                         2          1          0          1
    Contractor Initiated           J5                         3          1          2          3
    State Initiated                J5                         4          1          2          3
    Home Initiated                 J5                         8          1          2          3
    Govt Request                   J5                        11          1          2          3
    Total                          J5                                    5          8         14
    


    If there is more than one jurisdiction (as there probably is), you likely want to

    order by jurisdiction, reopening_order
    

    instead of ordering by REOPENING_ORDER alone.

  • User_WVSC7
    User_WVSC7 Member Posts: 292 Bronze Badge

    I tried the below method , and may be this seems to be working for your req.

    I am not sure how to format the below report properly , I tried to format it better , didn't work for me :)

    compute sum of r1 on REPORT

    SQL> compute sum of r2 on REPORT
    SQL> compute sum of r3 on REPORT
    SQL> compute sum of r4 on REPORT
    SQL> break on report
    select ro_type,jurisdiction,sum(reopening_order) r1,sum(ro_pending) r2,sum(ro_waiting) r3,sum(ro_granted) r4
      2 from t1_temp
      3 group by ro_type,jurisdiction
      4 order by r1;
    
    RO_TYPE JURISDICTI R1 R2 R3 R4
    ------------------------------ ---------- ---------- ---------- ---------- ----------
    Provider Requested J5 1 0 0 1
    Appeal J5 2 1 0 1
    Contractor Initiated J5 3 1 2 3
    State Initiated J5 4 1 2 3
    Home Initiated J5 8 1 2 3
    Govt Request J5 11 1 2 3
      ---------- ---------- ---------- ----------
    sum 29 5 8 14
    
    6 rows selected.