Showing posts with label SQL. Show all posts
Showing posts with label SQL. Show all posts

Friday, December 8, 2023

How to generate a cold backup script for a database

Probably many ways to to this, but here is how I generated a simple file that after being made executable will copy all files to a specific folder. The database must be shut down before running the script, so in other words, this will be a good, old-fashioned cold backup!
set lines 200
set pages 0
set trimspool on
set heading off
set echo off
set feedback off
set verify off

spool cp_files.sh


SELECT    'cp '
       || a.file_name
       || ' /u01/oracle/cold_backup/'
       || (SELECT TRIM (SUBSTR (b.file_name,
                                (  INSTR (b.file_name,
                                          '/',
                                          -1,
                                          1)
                                 + 1)))
             FROM cdb_data_files b
            WHERE a.file_name = b.file_name)
  FROM cdb_data_files a
UNION
SELECT    'cp '
       || a.MEMBER
       || ' /u01/oracle/cold_backup/'
       || (SELECT TRIM (SUBSTR (b.MEMBER,
                                (  INSTR (b.MEMBER,
                                          '/',
                                          -1,
                                          1)
                                 + 1)))
             FROM v$logfile b
            WHERE a.MEMBER = b.MEMBER)
FROM v$logfile A
UNION
SELECT    'cp '
       || a.name
       || ' /u01/oracle/cold_backup/'
       || (SELECT TRIM (SUBSTR (b.name,
                                (  INSTR (b.name,
                                          '/',
                                          -1,
                                          1)
                                 + 1)))
             FROM v$tempfile b
            WHERE a.name = b.name)
  FROM v$tempfile a
UNION
SELECT    'cp '
       || a.name
       || ' /u01/oracle/cold_backup/'
       || (SELECT TRIM (SUBSTR (b.name,
                                (  INSTR (b.name,
                                          '/',
                                          -1,
                                          1)
                                 + 1)))
             FROM v$controlfile b
            WHERE a.name = b.name)
  FROM v$controlfile a;

Friday, February 5, 2021

Find duplicate file names

You can find duplicate file names, on different file systems, by using this query:
set lines 200
col "file_name" format a30
col "tablespace" format a30

set trimspool on
spool duplicates.lst
alter session set nls_language='american';

select t.name "tablespace",
trim(
            substr(f.name,
                (instr(f.name,'/', -1, 1) +1)
                )
               ) "file_name", count(*)
from v$datafile f join v$tablespace t
on (f.ts# = t.ts#)
group by t.name,
         trim(
            substr(f.name,
                (instr(f.name,'/', -1, 1) +1)
                )
               )
having count(*) > 1;



exit

Wednesday, May 13, 2020

How to use the TIMESTAMP_TO_SCN function


select timestamp_to_scn(to_timestamp('2020-05-11 14:36:22', 'YYYY-MM-DD HH24:MI:SS')) "scn" from dual;

scn
----------
20325895

Reversed:
select scn_to_timestamp(20325895) "timestamp" from dual;

timestamp
----------------------------------
11-MAY-20 02.36.20.000000000 PM

Thursday, February 20, 2020

What does the SELECT ... FOR UPDATE statement do?



From the documentation:

The FOR UPDATE clause lets you lock the selected rows so that other users cannot lock or update the rows until you end your transaction. You can specify this clause only in a top-level SELECT statement, not in subqueries.

Some examples here

Used in PL/SQL:

The SELECT statement with the FOR UPDATE clause (SELECT FOR UPDATE statement) selects the rows of the result set and locks them. SELECT FOR UPDATE lets you base an update on the existing values in the rows, because it ensures that no other user can change those values before you update them.

Friday, August 9, 2019

How to find the number of executions for a specific SQL ID during a day



This query will gather data from DBA_HIST_ACTIVE_SESS_HISTORY for a specific day, and count the number of executions within that day:
select to_char(sample_time,'dd.mm.yyyy hh24') "day", count(*) "num executions"
from DBA_HIST_ACTIVE_SESS_HISTORY 
where sql_id = '7x0v1s9aq4y9t'
and to_date(to_char(sample_time,'dd.mm.yyyy')) = '05.08.2019'
group by to_char(sample_time,'dd.mm.yyyy hh24')
order by 1 desc;

day num executions
05.08.2019 23 302
05.08.2019 22 285
05.08.2019 21 333
05.08.2019 20 300
05.08.2019 19 393
05.08.2019 18 255
05.08.2019 17 351
05.08.2019 16 426
05.08.2019 15 450
05.08.2019 14 624
05.08.2019 13 842
05.08.2019 12 621
05.08.2019 11 503
05.08.2019 10 461
05.08.2019 09 444
05.08.2019 08 279
05.08.2019 07 148
05.08.2019 06 79
05.08.2019 05 77
05.08.2019 04 80
05.08.2019 03 3396
05.08.2019 02 3680
05.08.2019 01 2808
05.08.2019 00 123

Tuesday, April 9, 2019

How to create a unique constraint with an existing index (the USING-clause)



Create the index:
CREATE UNIQUE INDEX MYTABLE_IDX1 ON MYTABLE
(ID,CATEGORY)
LOCAL
TABLESPACE USERS
ONLINE;

Create a unique constraint:
ALTER TABLE MYTABLE ADD (
CONSTRAINT UK_MYTABLE
UNIQUE (ID,CATEGORY)
USING INDEX MYTABLE_IDX1
);

For a primary key constraint the syntax is similar.
In this example, an index named MYTABLE_PK will be automatically created on the fly:
ALTER TABLE MYTABLE ADD (
CONSTRAINT MYTABLE_PK
PRIMARY KEY (ID)
USING INDEX);

Monday, January 28, 2019

How to enable DML logging



DML logging can be used as a workaround if you have a large number of rows to process, and you expect that some of these will fail to be inserted correctly due to data quality problems. In other words, some rows may violate one or more constraints on the receiving table.

Here is a short demonstration that I have recently tested as a workaround for a client.

I have a table called MYTABLE, which looks like this:
 Name                   Null?    Type
 --------------------- -------- -------------------
 ORDER_ID                        NOT NULL NUMBER
 ORG_ORDERID                     NUMBER
 VALUE_ID_TYPE                   VARCHAR2(20)
 COL_PREFIX                      VARCHAR2(80)
 COL_NAME                        VARCHAR2(500)
 COL_SUFFIX                      VARCHAR2(20)

There is a unique constraint on the table:
--create the index
CREATE UNIQUE INDEX C_COL_UIX ON MYTABLE
(ORG_ORDERID, COL_PREFIX, COL_NAME, COL_SUFFIX)
TABLESPACE USERS;

-- create the constraint, using index created above
ALTER TABLE MYTABLE ADD (
  CONSTRAINT C_COL_CONS
  UNIQUE (ORG_ORDERID, COL_PREFIX, COL_NAME, COL_SUFFIX)
  USING INDEX C_COL_UIX);

The actual DML logging is performed by adding the statement
LOG ERRORS INTO error_table ('INSERT') REJECT LIMIT UNLIMITED;
at the end of the INSERT statement.

Before we can do this we need to create the error log table:
BEGIN
  DBMS_ERRLOG.create_error_log (dml_table_name => 'MYTABLE');
END;
/

The statement above will create a table called ERR$_MYTABLE, where rejected rows will be inserted into.

For this test, I will now verify that the values I intend to use, actually exist in the table:
select count(*)
from mytable
where org_orderid = 122
and col_prefix = 'A'
and col_name = 'B'
and col_suffix = 'X'
;

  COUNT(*)
----------
         1

Any attempt to insert a row into the table with the same values as in the select statement above (122, A, B, X), will violate constraint C_COL_CONS, and logged in the table ERR$_MYTABLE.

Let's execute an INSERT statement that will violate the constraint:
INSERT
INTO mytable (order_id, col_prefix, col_name, col_suffix, col_type)
VALUES(122, 'A', 'B', 'X', 'D')
LOG ERRORS INTO ERR$_MYTABLE ('INSERT') REJECT LIMIT UNLIMITED;

As expected, I get the following error:
ORA-00001: unique constraint (C_COL_CONS) violated


Let's check the log table:
SELECT * FROM ERR$_MYTABLE;

ORA_ERR_NUMBER$ ORA_ERR_MESG$ ORA_ERR_ROWID$ ORA_ERR_OPTYP$ ORA_ERR_TAG$ ORDER_ID ORG_ORDERID VALUE_ID_TYPE COL_PREFIX COL_NAME COL_SUFFIX
1
ORA-00001: unique constraint (C_COL_CONS; violated   I INSERT 2850841 122 D A B X

If you execute a batchjob with thousands of rows, the offending rows will be caught so they can be corrected later. The non-offending rows will be neatly inserted where they belong.

Sunday, October 7, 2018

How to list all schemas and their sizes


If you want a list of schema sizes, join dba_segments with dba_users to limit the extract to users that are non-oracle maintained:
set lines 200
col owner  format a30
col "GB" format 999999
SELECT s.owner,sum(s.bytes/1024/1024/1024) "GB"
FROM dba_segments s join dba_users u
on (s.owner = u.username)
where u.oracle_maintained = 'N'
group by owner
ORDER BY 2 desc;

Example output
OWNER                               GB
------------------------------ -------
USER1                            19577
USER2                             6144
USER3                             2306

Thursday, March 15, 2018

The error

SP2-0552: Bind variable "B2" not declared.

can arise when using incorrect declarations in your SQL scripts.

For example, I had the follwing in a script:
var B2 DATE;
EXEC :B2 := to_date('22.02.2018','dd.mm.yyyy');

For sqlplus to accept this string, you need to declare your string as VARCHAR2, even though you intend to use datatype DATE in your query.

Declare it as VARCHAR instead:

var B2 VARCHAR2(10);


Thursday, August 31, 2017

How to explain a SQL statement using bind variables

Sometimes I am asked to analyze an SQL statement picked up from Enterprise Manager Cloud Control.
These SQL statements only reveal the bind variables used, and not their actual values.

To get a more realistic explain plan, ask your developers to provide you with the actual literal values used in the SQL statement, and then prepare a script that contains the following:
connect username/password
SET TIMING ON
SET LINESIZE 200
SET PAGESIZE 0

var b9 number;
var b8 number;
var b7 number;
var b6 varchar2(3);
var b5 varchar2(3);
var b4 varchar2(4);
var b3 varchar2(1);
var b2 varchar2(2);
var b1 varchar2(2);

exec :B9 := 12345;
exec :B8 := 6127737;
exec :B7 := 2013;
exec :B6 := 'KOC';
exec :B5 := 'PPQ';
exec :B4 := 'OOPQ';
exec :B3 := '7';
exec :B2 := 'YM';
exec :B1 := 'WT';

EXPLAIN PLAN FOR
  SELECT ...
  FROM ...
  WHERE COL1 NOT IN (:B6, :B5, :B4)
  AND COL2 = :8
  AND COL3 = :9;


SELECT * FROM table(DBMS_XPLAN.DISPLAY);

Run the script using sqlplus.

Such a script can also come in handy if you're asked to perform changes to the tables' structure, and then execute the actual script to see how much time it takes to execute.
In this case, remove the EXPLAIN PLAN clause and the call to DBMS_XPLAN.DISPLAY, and you'll have all you need to execute the actual SQL statements you're tuning.

Tuesday, March 14, 2017

How to use the Oracle 12c Row-limiting clauses

One of the most useful features of Oracle 12c is the ability to limit the number of rows from a query using top-N queries. Amongst others, they provide a great way to populate test tables.

It can be used in several ways, by specifying an offset of rows to skip, the number of rows to return or the percentage of rows to return.

A couple of simple examples:

Fetch the first 5 rows from the result set:
select * 
from scott.emp
fetch first 5 rows only;

Fetch the next 10 rows after the first five rows have been skipped:
select *  
from Scott.emp 
offset 5 rows fetch next 10 rows only;

Load the first few rows of data from a specific partition, into a new table:
insert into test_table
SELECT  *
FROM       original_table
subpartition (other_sp_default)
fetch first 10 rows only;

Sources:

http://docs.oracle.com/database/121/SQLRF/statements_10002.htm#BABHFGAA

and

http://docs.oracle.com/database/121/SQLRF/statements_10002.htm#BABEAACC

Wednesday, February 22, 2017

Insert As Select statements

The syntax for an Insert As Select Statement would be:
INSERT INTO MY_INTERIM_TABLE (E_ID, ENAME,CREATED_DT, REVISION, FISCALYEAR, FPERIOD, PHONENBR)
                       SELECT E_ID, ENAME,CREATED_DT, REVISION, FISCALYEAR, TO_DATE(FPERIOD,'YYYY-MM'), PHONENBR
                       FROM   MY_ORIGINAL_TABLE
                       FETCH FIRST 5 ROWS ONLY;

The FETCH FIRST num ROWS ONLY is a convenient way to limit the number of rows when you are setting up tables for test purposes.

Wednesday, February 1, 2017

How to display a SYSTIMESTAMP data type as a TIMESTAMP WITH TZ

To display a value of datatype SYSTIMESTAMP as TIMESTAMP WITH TIME ZONE, use TO_CHAR first, then convert to TIMESTAMP WITH TIMEZONE.

The last expression adds one hour, which can be done after the conversion between the datatypes is complete:
select  TO_CHAR(SYSTIMESTAMP,'yyyy/mm/dd hh24:mi:ss.ff tzh:tzm'),
        TO_TIMESTAMP_TZ(to_char(SYSTIMESTAMP,'yyyy/mm/dd hh24:mi:ss.ff tzh:tzm'),'yyyy/mm/dd hh24:mi:ss.ff tzh:tzm'),
        TO_TIMESTAMP_TZ(to_char(SYSTIMESTAMP,'yyyy/mm/dd hh24:mi:ss.ff tzh:tzm'),'yyyy/mm/dd hh24:mi:ss.ff tzh:tzm')+1/24
from dual;
systimestamp TIMESTAMP_TZ TIMESTAMP_TZ + 1hr
2017/02/01 10:36:28.158921 +01:00 01/02/2017 10:36:28,158921000 +01:00 01.02.2017 11:36:28

Thursday, December 15, 2016

How to create a line-by-line comparison between the parameters used in two different databases

Here is a simple way to create a line-by-line comparison between two databases over a database link.

First make sure there is tns Connectivity between the database you execute the script in, and the remote database.

Then, create a datatabase link:
-- create db link from prod to test
create public database link testdb
connect to system
identified by ****
using 'testdb';

-- make sure that the link works before you proceed:
select host_name from v$instance@testdb;

The following script will spool a text file to your current directory, which can be investigated for differences between the two databases' initialization parameters:
set trimspool on
spool parameter_comparison.lst
set lines 200
col name format a40
col "test value" format a50
col "prod value" format a50
select prod.name,prod.value "prod value",test.value "test value"
from v$system_parameter prod full outer join v$system_parameter@testdb test
on prod.name = test.name;

exit

Wednesday, August 24, 2016

How to add minutes, seconds, hours or days to a datetime value

Simply add the desired interval to your timestamp value:

select current_timestamp,
       current_timestamp + interval '3' minute "current_timestamp+3min" 
from dual;


CURRENT_TIMESTAMP                                 current_timestamp+3min
----------------------------------------          ---------------------------------------------------------------------------
24.08.2016 19.44.32,808781 +2:00                  24.08.2016 19.47.32,808781000 +2:00

There are numerous possibilities to add very granular time intervals to an existing datetime value.

Check the examples of Interval literals in the official documentation.

Friday, August 19, 2016

Example on how to use WITH CHECK OPTION in an INSERT statement



The table "ALBUM" has the following columns:
Name         Null     Type                        
------------ -------- --------------------------- 
ALBUM_ID     NOT NULL NUMBER                      
ALBUM_TITLE  NOT NULL VARCHAR2(50 CHAR)           
ARTIST_ID             NUMBER                      
RELEASE_DATE          TIMESTAMP(6) WITH TIME ZONE 
GENRE                 VARCHAR2(30)                
NUM_SOLD              NUMBER                      
COLLECTION            CHAR(1)        

Extract all albums by the band Kiss:
SELECT ARTIST_ID, ALBUM_TITLE
 FROM ALBUM
 WHERE ARTIST_ID = (SELECT ARTIST_ID FROM ARTIST WHERE ARTIST_NAME='Kiss');

 ARTIST_ID ALBUM_TITLE                                      
---------- ------------
        13 Dynasty            

Add another entry to the "ALBUM" table:
SQL> INSERT INTO
  2  (
  3   SELECT album_id, album_title, artist_id,release_date, genre, num_sold
  4   FROM album
  5   WHERE num_sold BETWEEN 10000 AND 50000
  6   AND artist_id=13 WITH CHECK OPTION
  7   )
  8   VALUES( album_seq.nextval, '&album_title', &artist_id, to_date('&release_date','dd.mm.yyyy'), 'HARD ROCK', 20000 );
Enter value for album_title: Love Gun
Enter value for artist_id: 13
Enter value for release_date: 30.06.1977
old   8:  VALUES( album_seq.nextval, '&album_title', &artist_id, to_date('&release_date','dd.mm.yyyy'), 'HARD ROCK', 20000 )
new   8:  VALUES( album_seq.nextval, 'Love Gun', 13, to_date('30.06.1977','dd.mm.yyyy'), 'HARD ROCK', 20000 )

1 row inserted.

COMMIT;
Run the SELECT above once more to confirm the row has been entred:
ARTIST_ID ALBUM_TITLE                                      
---------- -----------------------
        13 Love Gun                             
        13 Dynasty            

Any attempt to enter values that is not included in the subquery would cause an
ORA-01402: view WITH CHECK OPTION where-clause violation
to be raised.
For example, try entering 15 as the artist_id:
Enter value for album_title: Creatures of the Night
Enter value for artist_id: 15
Enter value for release_date: 13.10.1982
old   8:  VALUES( album_seq.nextval, '&album_title', &artist_id, to_date('&release_date','dd.mm.yyyy'), 'HARD ROCK', 20000 )
new   8:  VALUES( album_seq.nextval, 'Creatures of the Night', 15, to_date('13.10.1982','dd.mm.yyyy'), 'HARD ROCK', 20000 )
 VALUES( album_seq.nextval, 'Creatures of the Night', 15, to_date('13.10.1982','dd.mm.yyyy'), 'HARD ROCK', 20000 )
         *
ERROR at line 8:
ORA-01402: view WITH CHECK OPTION where-clause violation

Note that the subquery, when used in an INSERT statement as above, replaces the table name, as well as the column list.

Source: Oracle documentation

Thursday, July 14, 2016

INTERVAL conversion functions

There are 4 convertions functions that deal with INTERVAL datatypes, as listed below.
The two first converts strings, the later two converts numbers. All functions returns data of datatype INTERVAL.

TO_DSINTERVAL(sql_format)

* Converts a string into a value of the INTERVAL DAY TO SECOND datatype
* sql_format is a character string in the required format, which is 'DAYS HH24:MI:SS.FF'
* For example, the string '2 8:30:15.444' would equal 2 days, 8 hours, 30 minutes, 15.444 seconds.

Output: A value of the INTERVAL DAY TO SECOND datatype

Example:

SELECT TO_DSINTERVAL(INTERVAL '4' HOUR) "HOUR"
FROM DUAL;

HOUR
+00 04:00:00.000000



TO_YMINTERVAL('y-m')
* Converts y and m into the years and months in a format recognized by the INTERVAL YEAR TO MONTH datatype
* y and m are numbers within a string

Output: A value of the INTERVAL YEAR TO MONTH datatype

Example:
SELECT TO_YMINTERVAL(INTERVAL '36' MONTH) "MONTH"
FROM DUAL;

MONTH
+03-00


NUMTOYMINTERVAL(n, u)

* Converts a number into a value that represents the u unit amount of time
n = number
u = 'YEAR' or 'MONTH'
* Output: a value of the INTERVAL YEAR TO MONTH datatype

Example:

SELECT NUMTOYMINTERVAL(4, 'MONTH') "MONTH"
FROM DUAL;

MONTH
+00-04


NUMTODSINTERVAL(n, u)
Converts a number into a value that represents the u unit amount of time
n = number
u = 'DAY', 'HOUR', 'MINUTE', 'SECOND'
Output: a value of the INTERVAL DAY TO SECOND datatype

Example:

SELECT NUMTODSINTERVAL(2,'MINUTE') "MINUTE"
FROM DUAL;

MINUTE
+00 00:02:00.000000

Wednesday, July 13, 2016

SYSTIMESTAMP and SYSDATE VS. CURRENT_TIMESTAMP and CURRENT_DAY

Most DBAs I've spoken to are familiar with the function SYSDATE, but there are some other functions, too, that may prove to be useful, even for DBAs that aren't directly involved in developing applications.
For example, when querying the data dictionary, it can certainly be an advantage to be familiar with some other built-in date functions that comes with the Oracle database.

The two first functions reflect the datetime settings of the operating system on which the database runs:

* The SYSTIMESTAMP function returns a value of the TIMESTAMP WITH TIME ZONE datatype. It includes fractional seconds and time zone.
* the SYSDATE function returns a value of the DATE datatype.It includes timestamp, but not fractional seconds, nor time stamp.

The three functions below reflects the settings of your session:

* The CURRENT_DATE fuction returns a value of the DATE datatype within the session time zone
* The CURRENT_TIMESTAMP function returns a value of the TIMESTAMP WITH TIME ZONE data type within the session time zone
* The LOCALTIMESTAMP function returns a value of the TIMESTAMP data type, within the session time zone

Sitting in Oslo and querying a database with dbtimezone set to +2:00:
select dbtimezone from dual;
DBTIME
+02:00
I get the following default output when I execute the queries at 11:45:


select sysdate, systimestamp, current_date,current_timestamp(5), localtimestamp(3) from dual

SYSDATE SYSTIMESTAMP CURRENT_DATE CURRENTTIMESTAMP LOCALTIMESTAMP
13.07.2016 11:45:52 13.07.2016 11.45.52,597707 +02:00 13.07.2016 11:45:52 13.07.2016 11.45.52,59771 +02:00 13.07.2016 11.45.52,598

Now I will change my session time zone:
alter session set time_zone='America/New_York';

Session altered.


Execute the functions again, and the difference between the function becomes apparent:
select sysdate, systimestamp, current_date,current_timestamp(5), localtimestamp(3) from dual;

SYSDATE SYSTIMESTAMP CURRENT_DATE CURRENTTIMESTAMP LOCALTIMESTAMP
13.07.2016 11:49:1513.07.2016 11.49.15,381888 +02:0013.07.2016 05:49:1513.07.2016 05.49.15,38189 AMERICA/NEW_YORK13.07.2016 05.49.15,382



Current_date now returns the date and time as it would be in New York
Current_timestamp does the same, but adds the region name as the time zone indicator
Localtimestamp returns the timestamp as it would be in New York

The precision in the current_timestamp and localtimestamp (5 and 3, respectively) are set to override the default precision of 6 for fractional seconds.

Tuesday, July 12, 2016

Overview of role privileges

The following UNION can be handy to get an overview of what system privileges, object privileges and other roles a specific role may contain:
Select  Role || ' contains role:' "role privilege type", Granted_Role "privilege"   From Role_Role_Privs Where Role='ONLINE_USERS'
Union
Select Role || ' contains system priv:', Privilege      From Role_Sys_Privs  Where Role='ONLINE_USERS'
Union
Select Role || ' contains object priv:',  Privilege || ' ON ' || owner || '.' || table_name From Role_Tab_Privs Where Role='ONLINE_USERS'
order by 1;

Output:


role privilege type privilege
ONLINE_USERS contains object priv: UPDATE ON SCOTT.EMP
ONLINE_USERS contains role: RESOURCE
ONLINE_USERS contains system priv: UPDATE ANY TABLE

Wednesday, July 6, 2016

A workaround for ORA-02287: sequence number not allowed here when using GROUP BY in a subquery

When you use GROUP BY in the subquery of an INSERT statement, Oracle will throw

ORA-02287: sequence number not allowed here 

if you try to reference a sequence's NEXTVAL pseudocolumn directly in the insert statement, like this:
INSERT INTO mytable
        (
        entry_id,   
        order_date, 
        sum(quantity)
        )
        MYSEQ.NEXTVAL, <-- INCORRECT
        SELECT  
            TRUNC(SYSDATE),
            SUM(quantity)
        FROM    orders
        WHERE   
        GROUP BY order_date
        ORDER BY 2 ASC, 3 DESC;
Solution is to create a trigger that will fire on INSERT statements, before a new row is inserted. Note that I am overriding the default correlation name NEW with NewID, by using the REFERENCING clause of the "CREATE TRIGGER" command:
CREATE OR REPLACE TRIGGER MYTRG
BEFORE INSERT ON mytable REFERENCING NEW as NewID
    FOR EACH ROW
        BEGIN
            SELECT myseq.NEXTVAL
            INTO :NewID.ENTRY_ID
            FROM DUAL;
        END;
Change your insert statement slightly:
INSERT INTO mytable
        (
        order_date, 
        sum(quantity)
        )
        SELECT  
            TRUNC(SYSDATE),
            SUM(quantity)
        FROM    orders
        WHERE   
        GROUP BY order_date
        ORDER BY 2 ASC, 3 DESC;