From 3567ab88b752bfb6c1e91c512c163e8f69f23c1c Mon Sep 17 00:00:00 2001 From: martin bach Date: Wed, 21 Jun 2023 16:47:55 +0200 Subject: [PATCH 1/5] (23.2.0) annotations --- features/annotations.adoc | 162 ++++++++++++++++++++++++++++++++++++++ 1 file changed, 162 insertions(+) create mode 100644 features/annotations.adoc diff --git a/features/annotations.adoc b/features/annotations.adoc new file mode 100644 index 0000000..fc646bf --- /dev/null +++ b/features/annotations.adoc @@ -0,0 +1,162 @@ += Annotations +:database-version: 23.2.0 +:database-category: sql + +[[feature_summary]] + +Annotations are a lightweight declarative facility for developers to centrally register usage properties for database schema objects. Annotations are stored in dictionary tables and available to any application looking to standardize behavior across common data in related applications. Annotations are not interpreted by the database in any way and are custom data properties for database metadata - including table columns, tables, and indexes. Applications can use annotations as additional property metadata for rendering user interfaces or customizing application logic. + +[source,sql] +[subs="verbatim"] +---- +-- example 01: table-level annotation + +CREATE TABLE customers ( + customer_id INTEGER GENERATED BY DEFAULT ON NULL AS IDENTITY, + email_address VARCHAR2(255 CHAR) NOT NULL, + full_name VARCHAR2(255 CHAR) NOT NULL +) +ANNOTATIONS ( + sensitivity 'high', + departments 'sales, delivery', + frontOffice +) +/ + +-- example 02: adding a column-level annotation + +ALTER TABLE customers MODIFY ( + email_address ANNOTATIONS ( sensitivity 'highest' ) +) +/ + +-- example 03: table and column level annotations + +CREATE TABLE employees +( + id NUMBER(5) + ANNOTATIONS ( + identity, + display_as 'Employee ID', + group_name 'Emp_Info'), + name VARCHAR2(50) + ANNOTATIONS ( + display_as 'Employee Name', + group_name 'Emp_Info'), + salary NUMBER + ANNOTATIONS ( + display_as 'Employee Salary', UI_hidden) +) +ANNOTATIONS ( + display_as 'Employee Table' +) +/ + +-- example 04: query the dictionary for annotation usage + +SELECT + object_name, + object_type, + column_name, + annotation_name, + annotation_value +FROM + user_annotations_usage +ORDER BY + object_name, + column_name +/ + +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> -- example 01: table-level annotation +SQL> CREATE TABLE customers ( + 2 customer_id INTEGER GENERATED BY DEFAULT ON NULL AS IDENTITY, + 3 email_address VARCHAR2(255 CHAR) NOT NULL, + 4 full_name VARCHAR2(255 CHAR) NOT NULL + 5 ) + 6 ANNOTATIONS ( + 7 sensitivity 'high', + 8 departments 'sales, delivery', + 9 frontOffice + 10 ) + 11 / + +Table CUSTOMERS created. + +SQL> -- example 02: adding a column-level annotation +SQL> ALTER TABLE customers MODIFY ( + 2 email_address ANNOTATIONS ( sensitivity 'highest' ) + 3 ) + 4 / + +Table CUSTOMERS altered. + +SQL> -- example 03: table and column level annotations +SQL> CREATE TABLE employees + 2 ( + 3 id NUMBER(5) + 4 ANNOTATIONS ( + 5 identity, + 6 display_as 'Employee ID', + 7 group_name 'Emp_Info'), + 8 name VARCHAR2(50) + 9 ANNOTATIONS ( + 10 display_as 'Employee Name', + 11 group_name 'Emp_Info'), + 12 salary NUMBER + 13 ANNOTATIONS ( + 14 display_as 'Employee Salary', UI_hidden) + 15 ) + 16 ANNOTATIONS ( + 17 display_as 'Employee Table' + 18 ) + 19 / + +Table EMPLOYEES created. + +SQL> -- example 04: query the dictionary for annotation usage +SQL> SELECT + 2 object_name, + 4 column_name, + 5 annotation_name, + 6 annotation_value + 7 FROM + 8 user_annotations_usage + 9 ORDER BY + 10 object_name, + 11 column_name + 12 / + +OBJECT_NAME COLUMN_NAME ANNOTATION_NAME ANNOTATION_VALUE +______________ ________________ __________________ ___________________ +CUSTOMERS EMAIL_ADDRESS SENSITIVITY highest +CUSTOMERS DEPARTMENTS sales, delivery +CUSTOMERS FRONTOFFICE +CUSTOMERS SENSITIVITY high +EMPLOYEES ID IDENTITY +EMPLOYEES ID GROUP_NAME Emp_Info +EMPLOYEES ID DISPLAY_AS Employee ID +EMPLOYEES NAME DISPLAY_AS Employee Name +EMPLOYEES NAME GROUP_NAME Emp_Info +EMPLOYEES SALARY DISPLAY_AS Employee Salary +EMPLOYEES SALARY UI_HIDDEN +EMPLOYEES DISPLAY_AS Employee Table + +12 rows selected. + +---- + +== Benefits + +Annotating the data model with metadata provides additional data integrity, consistency and data model documentation benefits. Your applications can store user-defined metadata for database objects and table columns that other applications or users can retrieve and use. Storing the metadata along with the data guarantees consistency and universal accessibility to any user or application that uses the data. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/cncpt/application-data-usage.html#GUID-D5D5615C-BB2C-4833-A9AF-6BAF0BF9CEC0[Database Concepts Guide] +* https://docs.oracle.com/en/database/oracle/oracle-database/23/adfns/registering-application-data-usage-database.html#GUID-2DAF069E-0938-40AF-B05B-75AFE71D666C[Database Development Guide] \ No newline at end of file From a69b7f30e2f9cd89daa2d036fed9b1620ad888f8 Mon Sep 17 00:00:00 2001 From: martin bach Date: Wed, 21 Jun 2023 16:49:02 +0200 Subject: [PATCH 2/5] (23.2.0) select without from clause --- features/select-without-from.adoc | 60 +++++++++++++++++++++++++++++++ 1 file changed, 60 insertions(+) create mode 100644 features/select-without-from.adoc diff --git a/features/select-without-from.adoc b/features/select-without-from.adoc new file mode 100644 index 0000000..1313597 --- /dev/null +++ b/features/select-without-from.adoc @@ -0,0 +1,60 @@ += SELECT without FROM clause +:database-version: 23.2.0 +:database-category: sql + +You can now run SELECT expression-only queries without a FROM clause, e.g. adding `from dual` is no longer needed in such cases. The `DUAL` table has not disappeared, all queries that use it will continue to work as expected. + +[source,sql] +[subs="verbatim"] +---- +select + 2 * 3; + +select + to_char( + sysdate, + 'dd.mm.yyyy' + ) as today; + +select + sysdate; +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> select + 2 2 * 3; + + 2*3 +---------- + 6 + +SQL> select + 2 to_char( + 3 sysdate, + 4 'dd.mm.yyyy' + 5 ) as today; + +TODAY +---------- +20.06.2023 + +SQL> select + 2 sysdate; + +SYSDATE +--------- +20-JUN-23 + +---- + +== Benefits + +Making the `from dual` clause optional in expression-only SQL statements improves SQL code portability and ease of use for developers. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/SELECT.html#GUID-CFA006CA-6FF1-4972-821E-6996142A51C6[Documentation] From edde516675c3ab8e74d360a1692ff2829825e22b Mon Sep 17 00:00:00 2001 From: martin bach Date: Thu, 22 Jun 2023 13:32:18 +0200 Subject: [PATCH 3/5] (23.2.0) returning into enhancements --- features/returning-into.adoc | 323 +++++++++++++++++++++++++++++++++++ 1 file changed, 323 insertions(+) create mode 100644 features/returning-into.adoc diff --git a/features/returning-into.adoc b/features/returning-into.adoc new file mode 100644 index 0000000..2c46d11 --- /dev/null +++ b/features/returning-into.adoc @@ -0,0 +1,323 @@ += Enhanced Returning-Into Clause +:database-version: 23.2.0 +:database-category: sql + +[[feature_summary]] + +The RETURNING INTO clause for `INSERT`, `UPDATE`, and `DELETE` statements are enhanced to report old and new values affected by the respective statement. This allows developers to use the same logic for each of these DML types to obtain values pre- and post-statement execution. Old and new values are valid only for `UPDATE` statements. `INSERT` statements don't report old values and `DELETE` statements don't report new values. + +[source,sql] +[subs="verbatim"] +---- + +-- example 01: returning old and new values for a single-row update +var l_old_salary number +var l_new_salary number + +UPDATE employees +SET + salary = salary * 1.07 +WHERE + employee_id = 103 +RETURNING + old salary, new salary +INTO + :l_old_salary, :l_new_salary; + +SELECT + :l_old_salary, + :l_new_salary; + +ROLLBACK; + +-- example 02: returning old and new values for a multi-row update +-- and storing the values in an audit table +DROP TABLE IF EXISTS employees_history; + +CREATE TABLE employees_history ( + employee_id NUMBER(6) NOT NULL, + old_salary NUMBER(8, 2) NOT NULL, + new_salary NUMBER(8, 2) NOT NULL, + changed_on DATE NOT NULL +); + +DECLARE + TYPE t_change_rec IS RECORD ( + old_salary employees_history.old_salary%TYPE, + new_salary employees_history.new_salary%TYPE, + employee_id employees_history.employee_id%TYPE + ); + TYPE t_change_details IS + TABLE OF t_change_rec; + l_changes t_change_details; +BEGIN + UPDATE employees e + SET + salary = salary * 1.07 + FROM departments d + WHERE + d.department_id = e.department_id + AND d.department_name = 'IT' + RETURNING + OLD salary, NEW salary, employee_id + BULK COLLECT INTO + l_changes; + + FORALL i IN 1..l_changes.count + INSERT INTO employees_history ( + employee_id, + old_salary, + new_salary, + changed_on + ) VALUES ( + l_changes(i).employee_id, + l_changes(i).old_salary, + l_changes(i).new_salary, + sysdate + ); +END; +/ + +SELECT + employee_id, + old_salary, + new_salary, + changed_on +FROM + employees_history; + +ROLLBACK; + +-- example 03: no "old" value returned by INSERT statements +DROP TABLE IF EXISTS insert_demo; + +CREATE TABLE insert_demo ( + id NUMBER + GENERATED ALWAYS AS IDENTITY, + vc VARCHAR2(100) NOT NULL, + d DATE DEFAULT sysdate NOT NULL, + CONSTRAINT pk_insert_demo PRIMARY KEY ( id ) +) +/ + +var l_old_id number +var l_new_id number + +INSERT INTO insert_demo ( + vc +) VALUES ( + 'insert demo' +) +RETURNING + old id, + new id +INTO + :l_old_id, + :l_new_id; + +SELECT + :l_old_id, + :l_new_id; + +-- example 04: no "new" value returning by DELETE statements +DELETE + insert_demo +WHERE + id = :l_new_id +RETURNING + old id, new id +INTO + :l_old_id, + :l_new_id; + +SELECT + :l_old_id, + :l_new_id; + +ROLLBACK; + +---- + +.Result +[source,sql] +[subs="verbatim"] +---- + +SQL> -- example 01: returning old and new values for a single-row update +SQL> var l_old_salary number +SQL> var l_new_salary number +SQL> UPDATE employees + 2 SET + 3 salary = salary * 1.07 + 4 WHERE + 5 employee_id = 103 + 6 RETURNING + 7 old salary, new salary + 8 INTO + 9 :l_old_salary, :l_new_salary; + +1 row updated. + +SQL> SELECT + 2 :l_old_salary, + 3 :l_new_salary; + +:L_OLD_SALARY :L_NEW_SALARY +------------- ------------- + 9000 9630 + +SQL> ROLLBACK; + +Rollback complete. + +SQL> -- example 02: returning old and new values for a multi-row update +SQL> -- and storing the values in an audit table +SQL> DROP TABLE IF EXISTS employees_history; + +Table dropped. + +SQL> CREATE TABLE employees_history ( + 2 employee_id NUMBER(6) NOT NULL, + 3 old_salary NUMBER(8, 2) NOT NULL, + 4 new_salary NUMBER(8, 2) NOT NULL, + 5 changed_on DATE NOT NULL + 6 ); + +Table created. + +SQL> DECLARE + 2 TYPE t_change_rec IS RECORD ( + 3 old_salary employees_history.old_salary%TYPE, + 4 new_salary employees_history.new_salary%TYPE, + 5 employee_id employees_history.employee_id%TYPE + 6 ); + 7 TYPE t_change_details IS + 8 TABLE OF t_change_rec; + 9 l_changes t_change_details; + 10 BEGIN + 11 UPDATE employees e + 12 SET + 13 salary = salary * 1.07 + 14 FROM departments d + 15 WHERE + 16 d.department_id = e.department_id + 17 AND d.department_name = 'IT' + 18 RETURNING + 19 OLD salary, NEW salary, employee_id + 20 BULK COLLECT INTO + 21 l_changes; + 22 + 23 FORALL i IN 1..l_changes.count + 24 INSERT INTO employees_history ( + 25 employee_id, + 26 old_salary, + 27 new_salary, + 28 changed_on + 29 ) VALUES ( + 30 l_changes(i).employee_id, + 31 l_changes(i).old_salary, + 32 l_changes(i).new_salary, + 33 sysdate + 34 ); + 35 END; + 36 / + +PL/SQL procedure successfully completed. + +SQL> SELECT + 2 employee_id, + 3 old_salary, + 4 new_salary, + 5 changed_on + 6 FROM + 7 employees_history; + +EMPLOYEE_ID OLD_SALARY NEW_SALARY CHANGED_O +----------- ---------- ---------- --------- + 103 9000 9630 22-JUN-23 + 104 6000 6420 22-JUN-23 + 105 4800 5136 22-JUN-23 + 106 4800 5136 22-JUN-23 + 107 4200 4494 22-JUN-23 + +SQL> ROLLBACK; + +Rollback complete. + +SQL> -- example 03: no "old" value returned by INSERT statements +SQL> DROP TABLE IF EXISTS insert_demo; + +Table dropped. + +SQL> CREATE TABLE insert_demo ( + 2 id NUMBER + 3 GENERATED ALWAYS AS IDENTITY, + 4 vc VARCHAR2(100) NOT NULL, + 5 d DATE DEFAULT sysdate NOT NULL, + 6 CONSTRAINT pk_insert_demo PRIMARY KEY ( id ) + 7 ) + 8 / + +Table created. + +SQL> var l_old_id number +SQL> var l_new_id number +SQL> INSERT INTO insert_demo ( + 2 vc + 3 ) VALUES ( + 4 'insert demo' + 5 ) + 6 RETURNING + 7 old id, + 8 new id + 9 INTO + 10 :l_old_id, + 11 :l_new_id; + +1 row created. + +SQL> SELECT + 2 :l_old_id, + 3 :l_new_id; + + :L_OLD_ID :L_NEW_ID +---------- ---------- + 1 + +SQL> -- example 04: no "new" value returning by DELETE statements +SQL> DELETE + 2 insert_demo + 3 WHERE + 4 id = :l_new_id + 5 RETURNING + 6 old id, new id + 7 INTO + 8 :l_old_id, + 9 :l_new_id; + +1 row deleted. + +SQL> SELECT + 2 :l_old_id, + 3 :l_new_id; + + :L_OLD_ID :L_NEW_ID +---------- ---------- + 1 + +SQL> ROLLBACK; + +Rollback complete. + +---- + +== Benefits + +The ability to obtain old and new values affected by INSERT, UPDATE, and DELETE statements, as part of the SQL command’s execution, offers developers a uniform approach to reading these values and reduces the amount of work the database must perform. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/DELETE.html#GUID-156845A5-B626-412B-9F95-8869B988ABD7__I2122564[SQL Language Reference: DELETE] +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/INSERT.html#GUID-903F8043-0254-4EE9-ACC1-CB8AC0AF3423__I2122356[SQL Language Reference: INSERT] +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/UPDATE.html#GUID-027A462D-379D-4E35-8611-410F3AC8FDA5__I2126358[SQL Language Reference: UPDATE] \ No newline at end of file From 968e8466be40877a717c1777be50257af795011c Mon Sep 17 00:00:00 2001 From: martin bach Date: Thu, 22 Jun 2023 16:26:19 +0200 Subject: [PATCH 4/5] extended case statement pl/sql --- features/extended-case-controls.adoc | 75 ++++++++++++++++++++++++++++ 1 file changed, 75 insertions(+) create mode 100644 features/extended-case-controls.adoc diff --git a/features/extended-case-controls.adoc b/features/extended-case-controls.adoc new file mode 100644 index 0000000..ce3eaf0 --- /dev/null +++ b/features/extended-case-controls.adoc @@ -0,0 +1,75 @@ += Extended CASE Controls +:database-version: 23.2.0 +:database-category: plsql + +[[feature_summary]] + +The `CASE` statement is extended in *PL/SQL* to be consistent with the updated definitions of `CASE` expressions and `CASE` statements in the `SQL:2003 Standard [ISO03a, ISO03b]`. + +At the time of writing there is no SQL equivalent of the extended PL/SQL `CASE` statement. + +[source,sql] +[subs="verbatim"] +---- +begin + -- example 01: assign grades to result percentages + for inx in -1, 19, 50, 75, 99, null loop + dbms_output.put_line ( + nvl ( to_char ( inx ), 'null' ) || ' = ' || + case inx + when < 0, > 100 then 'invalid result' + when is null then 'no result' + when between 90 and 100 then 'A' + when >= 80 then 'B' + when >= 70 then 'C' + when >= 60 then 'D' + when >= 50 then 'E' + else 'fail' + end + ); + end loop; +end; +/ +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> begin + 2 -- example 01: assign grades to result percentages + 3 for inx in -1, 19, 50, 75, 99, null loop + 4 dbms_output.put_line ( + 5 nvl ( to_char ( inx ), 'null' ) || ' = ' || + 6 case inx + 7 when < 0, > 100 then 'invalid result' + 8 when is null then 'no result' + 9 when between 90 and 100 then 'A' + 10 when >= 80 then 'B' + 11 when >= 70 then 'C' + 12 when >= 60 then 'D' + 13 when >= 50 then 'E' + 14 else 'fail' + 15 end + 16 ); + 17 end loop; + 18 end; + 19 / +-1 = invalid result +19 = fail +50 = E +75 = C +99 = A +null = no result + +PL/SQL procedure successfully completed. +---- + +== Benefits + +Dangling predicates allow tests other than equality to be performed in simple `CASE` operations. Multiple choices in `WHEN` clauses allow `CASE` operations in *PL/SQL* to be written with less duplicated code. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/lnpls/CASE-statement.html#GUID-F4251A23-0284-4990-A156-00A92F83BC35[Database PL/SQL Language Reference] From 187f6ff6ca91e009a7e23640dfa81b620f36f6d3 Mon Sep 17 00:00:00 2001 From: martin bach Date: Fri, 23 Jun 2023 14:35:58 +0200 Subject: [PATCH 5/5] (23.2.0) returning into enhancements clarification --- features/returning-into.adoc | 6 +++++- 1 file changed, 5 insertions(+), 1 deletion(-) diff --git a/features/returning-into.adoc b/features/returning-into.adoc index 2c46d11..f6b588a 100644 --- a/features/returning-into.adoc +++ b/features/returning-into.adoc @@ -4,7 +4,11 @@ [[feature_summary]] -The RETURNING INTO clause for `INSERT`, `UPDATE`, and `DELETE` statements are enhanced to report old and new values affected by the respective statement. This allows developers to use the same logic for each of these DML types to obtain values pre- and post-statement execution. Old and new values are valid only for `UPDATE` statements. `INSERT` statements don't report old values and `DELETE` statements don't report new values. +The RETURNING INTO clause for `INSERT`, `UPDATE`, and `DELETE` statements are enhanced to report old and new values affected by the respective statement. This allows developers to use the same logic for each of these Data Manipulation Language (DML) types to obtain values pre- and post-statement execution. The following rules apply: + +* `UPDATE` statements report old and new values. +* `INSERT` statements only report new values. +* `DELETE` statements only report old values. [source,sql] [subs="verbatim"]