|
| 1 | += IF [NOT] EXISTS |
| 2 | +:database-version: 23.2.0 |
| 3 | +:database-category: sql |
| 4 | + |
| 5 | +The `IF [NOT] EXISTS` syntax can be used to ignore errors when dropping objects |
| 6 | +that do not exist or create objects that already exist. |
| 7 | + |
| 8 | +* Objects can now be dropped via `DROP IF EXISTS <object_type>` |
| 9 | +* Objects can now be created via `CREATE IF NOT EXISTS <object_type>` |
| 10 | +
|
| 11 | +[source,sql] |
| 12 | +[subs="verbatim"] |
| 13 | +---- |
| 14 | +-- Drop table if left over from a previous incomplete test run |
| 15 | +-- (this will produce an error) |
| 16 | +DROP TABLE my_test; |
| 17 | +
|
| 18 | +-- Recreate the table in a clean state |
| 19 | +CREATE TABLE my_test |
| 20 | +( |
| 21 | + id NUMBER NOT NULL PRIMARY KEY, |
| 22 | + name VARCHAR2(255), |
| 23 | + created_tms DATE DEFAULT SYSDATE NOT NULL |
| 24 | +); |
| 25 | +
|
| 26 | +-- Execute INSERT INTO tests for default value |
| 27 | +INSERT INTO my_test (id, name) VALUES (1, 'Test'); |
| 28 | +
|
| 29 | +-- Clean up test |
| 30 | +DROP TABLE my_test; |
| 31 | +
|
| 32 | +-- |
| 33 | +-- Second test run |
| 34 | +-- |
| 35 | +
|
| 36 | +-- Drop table if left over from a previous incomplete test run |
| 37 | +-- (the table has already been dropped in a previous test run, |
| 38 | +-- however, due to using IF EXISTS, no error will be raised) |
| 39 | +DROP TABLE IF EXISTS my_test; |
| 40 | +
|
| 41 | +-- Recreate the table in a clean state |
| 42 | +CREATE TABLE my_test |
| 43 | +( |
| 44 | + id NUMBER NOT NULL PRIMARY KEY, |
| 45 | + name VARCHAR2(255), |
| 46 | + created_tms DATE DEFAULT SYSDATE NOT NULL |
| 47 | +); |
| 48 | +
|
| 49 | +-- Execute INSERT INTO tests for default value of `created_tms` |
| 50 | +INSERT INTO my_test (id, name) VALUES (1, 'Test'); |
| 51 | +
|
| 52 | +-- Clean up test |
| 53 | +DROP TABLE my_test; |
| 54 | +---- |
| 55 | + |
| 56 | +.Result |
| 57 | +[source,sql] |
| 58 | +[subs="verbatim"] |
| 59 | +---- |
| 60 | +SQL> -- Drop table if left over from a previous incomplete test run |
| 61 | +SQL> -- (this will produce an error) |
| 62 | +SQL> DROP TABLE my_test; |
| 63 | +
|
| 64 | +Error starting at line : 1 in command - |
| 65 | +DROP TABLE my_test |
| 66 | +Error report - |
| 67 | +ORA-00942: table or view does not exist |
| 68 | +00942. 00000 - "table or view does not exist" |
| 69 | +*Cause: |
| 70 | +*Action: |
| 71 | +SQL> |
| 72 | +SQL> -- Recreate the table in a clean state |
| 73 | +SQL> CREATE TABLE my_test |
| 74 | + 2 ( |
| 75 | + 3 id NUMBER NOT NULL PRIMARY KEY, |
| 76 | + 4 name VARCHAR2(255), |
| 77 | + 5 created_tms DATE DEFAULT SYSDATE NOT NULL |
| 78 | + 6* ); |
| 79 | +
|
| 80 | +Table MY_TEST created. |
| 81 | +
|
| 82 | +SQL> |
| 83 | +SQL> -- Execute INSERT INTO tests for default value of `created_tms` |
| 84 | +SQL> INSERT INTO my_test (id, name) VALUES (1, 'Test'); |
| 85 | +
|
| 86 | +1 row inserted. |
| 87 | +
|
| 88 | +SQL> |
| 89 | +SQL> -- Clean up test |
| 90 | +SQL> DROP TABLE my_test; |
| 91 | +
|
| 92 | +Table MY_TEST dropped. |
| 93 | +
|
| 94 | +SQL> |
| 95 | +SQL> -- |
| 96 | + 2* -- Second test run |
| 97 | +SQL> -- |
| 98 | + 2* |
| 99 | +SQL> -- Drop table if left over from a previous incomplete test run |
| 100 | +SQL> -- (the table has already been dropped in a previous test run, |
| 101 | +SQL> -- however, due to using IF EXISTS, no error will be raised) |
| 102 | +SQL> DROP TABLE IF EXISTS my_test; |
| 103 | +
|
| 104 | +Table MY_TEST dropped. |
| 105 | +
|
| 106 | +SQL> |
| 107 | +SQL> -- Recreate the table in a clean state |
| 108 | +SQL> CREATE TABLE my_test |
| 109 | + 2 ( |
| 110 | + 3 id NUMBER NOT NULL PRIMARY KEY, |
| 111 | + 4 name VARCHAR2(255), |
| 112 | + 5 created_tms DATE DEFAULT SYSDATE NOT NULL |
| 113 | + 6* ); |
| 114 | +
|
| 115 | +Table MY_TEST created. |
| 116 | +
|
| 117 | +SQL> |
| 118 | +SQL> -- Execute INSERT INTO tests for default value |
| 119 | +SQL> INSERT INTO my_test (id, name) VALUES (1, 'Test'); |
| 120 | +
|
| 121 | +1 row inserted. |
| 122 | +
|
| 123 | +SQL> |
| 124 | +SQL> -- Clean up test |
| 125 | +SQL> DROP TABLE my_test; |
| 126 | +
|
| 127 | +Table MY_TEST dropped. |
| 128 | +---- |
| 129 | + |
| 130 | +== Benefits |
| 131 | + |
| 132 | +Ignoring the error when dropping a non existing object or creating an object |
| 133 | +that already exists can be very useful especially in testing scripts that always |
| 134 | +want to ensure a clean state at the beginning of tests but not produce |
| 135 | +false positives by e.g. receiving an error when dropping an object that does not exist. |
| 136 | + |
| 137 | +== Further information |
| 138 | + |
| 139 | +* Introduced: xref:versions:{database-version}/index.adoc[] |
| 140 | +* Availability: All Offerings |
| 141 | +* link:https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/DROP-TABLE.html#GUID-39D89EDC-155D-4A24-837E-D45DDA757B45[`DROP TABLE` documentation] |
| 142 | + |
0 commit comments