From 6919bbd48bec66ca0c824a8156268226baed7248 Mon Sep 17 00:00:00 2001 From: CSAXON Date: Fri, 1 Sep 2023 15:48:35 +0100 Subject: [PATCH] More 23c features --- .../ceil-floor-round-for-datetime-types.adoc | 73 +++++++ features/default-on-null-update.adoc | 130 +++++++++++ features/fuzzy-match-operator.adoc | 124 +++++++++++ features/json-plsql-type-conversions.adoc | 121 +++++++++++ features/phonic-encode-operator.adoc | 78 +++++++ features/schema-level-privileges.adoc | 80 +++++++ features/sql-transpiler.adoc | 201 ++++++++++++++++++ features/sum-and-avg-over-interval-types.adoc | 46 ++++ 8 files changed, 853 insertions(+) create mode 100644 features/ceil-floor-round-for-datetime-types.adoc create mode 100644 features/default-on-null-update.adoc create mode 100644 features/fuzzy-match-operator.adoc create mode 100644 features/json-plsql-type-conversions.adoc create mode 100644 features/phonic-encode-operator.adoc create mode 100644 features/schema-level-privileges.adoc create mode 100644 features/sql-transpiler.adoc create mode 100644 features/sum-and-avg-over-interval-types.adoc diff --git a/features/ceil-floor-round-for-datetime-types.adoc b/features/ceil-floor-round-for-datetime-types.adoc new file mode 100644 index 0000000..00b5f47 --- /dev/null +++ b/features/ceil-floor-round-for-datetime-types.adoc @@ -0,0 +1,73 @@ += CEIL, FLOOR, and ROUND for datetime data types +:database-version: 23.2 +:database-category: sql + +[[feature_summary]] + +You can now pass `DATE`, `TIMESTAMP`, and `INTERVAL` values to the `CEIL` and `FLOOR` functions. These functions include an optional second argument to specify a rounding unit. You can also pass `INTERVAL` values to `ROUND` and `TRUNC` functions. + +[source,sql] +[subs="verbatim"] +---- +with vals as ( + select + interval '+123-5' year(9) to month ymi, + interval '+0 12:34:56' day to second dsi, + to_date ( '12-APR-2023 12:34:56', 'DD-MON-YYYY HH24:MI:SS' ) dt, + to_timestamp ( '12-APR-2023 12:34:56', 'DD-MON-YYYY HH24:MI:SS' ) ts +) +select + -- CEIL rounds up values + ceil ( ymi ) as year_ceil, + ceil ( dsi ) as day_ceil, + ceil ( dt ) as dt_day_ceil, + ceil ( ts ) as ts_day_ceil, + -- FLOOR rounds down the datetime value to the units in the second paramter + floor ( ymi, 'year' ) as ymi_year_floor, + floor ( dsi, 'hh24' ) as dsi_hour_floor, + floor ( dt, 'hh24' ) as dt_hour_floor, + floor ( ts, 'hh24' ) as ts_hour_floor, + -- ROUND now supports INTERVALs + round ( dsi, 'mi' ) as dsi_minute_round +from vals; +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> with vals as ( + 2 select + 3 interval '+123-5' year(9) to month ymi, + 4 interval '+0 12:34:56' day to second dsi, + 5 to_date ( '12-APR-2023 12:34:56', 'DD-MON-YYYY HH24:MI:SS' ) dt, + 6 to_timestamp ( '12-APR-2023 12:34:56', 'DD-MON-YYYY HH24:MI:SS' ) ts + 7 ) + 8 select + 9 -- CEIL rounds up values + 10 ceil ( ymi ) as year_ceil, + 11 ceil ( dsi ) as day_ceil, + 12 ceil ( dt ) as dt_day_ceil, + 13 ceil ( ts ) as ts_day_ceil, + 14 -- FLOOR rounds down the datetime value to the units in the second paramter + 15 floor ( ymi, 'year' ) as ymi_year_floor, + 16 floor ( dsi, 'hh24' ) as dsi_hour_floor, + 17 floor ( dt, 'hh24' ) as dt_hour_floor, + 18 floor ( ts, 'hh24' ) as ts_hour_floor, + 19 -- ROUND now supports INTERVALs + 20 round ( dsi, 'mi' ) as dsi_minute_round + 21 from vals; + +YEAR_CE DAY_CEIL DT_DAY_CEIL TS_DAY_CEIL YMI_YEA DSI_HOUR_FLOOR DT_HOUR_FLOOR TS_HOUR_FLOOR DSI_MINUTE_ROUND +------- ------------------- ----------------- ----------------- ------- ------------------- ----------------- ----------------- ------------------- ++124-00 +01 00:00:00.000000 13-APR-2023 00:00 13-APR-2023 00:00 +123-00 +00 12:00:00.000000 12-APR-2023 12:00 12-APR-2023 12:00 +00 12:35:00.000000 +---- + +== Benefits + +These functions make it easy to find the upper and lower bounds for date and time values for a specified unit. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/ROUND-and-TRUNC-Date-Functions.html#GUID-8E10AB76-21DA-490F-A389-023B648DDEF8[CEIL, FLOOR, ROUND, and TRUNC Date Functions Documentation] diff --git a/features/default-on-null-update.adoc b/features/default-on-null-update.adoc new file mode 100644 index 0000000..c6ec9cd --- /dev/null +++ b/features/default-on-null-update.adoc @@ -0,0 +1,130 @@ += Default ON NULL for UPDATE statements +:database-version: 23.2 +:database-category: sql + +[[feature_summary]] + +You can specify a default value when updating a column to `NULL`. The database assigns the default value to the column instead of `NULL`. + +[source,sql] +[subs="verbatim"] +---- +create table default_values ( + id integer, + c1 number default extract ( second from systimestamp ), + c2 number default on null extract ( second from systimestamp ), + c3 number default on null for insert only extract ( second from systimestamp ), + c4 number default on null for insert and update extract ( second from systimestamp ) +); + +-- For the columns with DEFAULT ON NULL, the database replaces NULL with the timestamp value +insert into default_values + values ( 1, null, null, null, null ); + +select * from default_values; + +-- The standard DEFAULT clause has no impact on UPDATEs, so C1 remains NULL +update default_values +set c1 = null; + +-- DEFAULT ON NULL adds an implicit NOT NULL constraint to the column +-- The default only applies on insert, so this raises an ORA-01407 error +update default_values +set c2 = null; + +-- DEFAULT ON NULL FOR INSERT ONLY is equivalent to DEFAULT ON NULL +-- So this also raises an ORA-01407 error +update default_values +set c3 = null; + +-- C4 is DEFAULT ON NULL FOR INSERT AND UPDATE +-- So the database replaces NULL with its default value +update default_values +set c4 = null; + +-- The value of C4 has changed; all other columns retain their INSERT value +select * from default_values; +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> create table default_values ( + 2 id integer, + 3 c1 number default extract ( second from systimestamp ), + 4 c2 number default on null extract ( second from systimestamp ), + 5 c3 number default on null for insert only extract ( second from systimestamp ), + 6 c4 number default on null for insert and update extract ( second from systimestamp ) + 7 ); + +Table created. + +SQL> +SQL> -- For the columns with DEFAULT ON NULL, the database replaces NULL with the timestamp value +SQL> insert into default_values + 2 values ( 1, null, null, null, null ); + +1 row created. + +SQL> +SQL> select * from default_values; + + ID C1 C2 C3 C4 +---------- ---------- ---------- ---------- ---------- + 1 1.585189 1.585189 1.585189 + +SQL> +SQL> -- The standard DEFAULT clause has no impact on UPDATEs, so C1 remains NULL +SQL> update default_values + 2 set c1 = null; + +1 row updated. + +SQL> +SQL> -- DEFAULT ON NULL adds an implicit NOT NULL constraint to the column +SQL> -- The default only applies on insert, so this raises an ORA-01407 error +SQL> update default_values + 2 set c2 = null; +set c2 = null + * +ERROR at line 2: +ORA-01407: cannot update ("CHRIS"."DEFAULT_VALUES"."C2") to NULL + + +SQL> +SQL> -- DEFAULT ON NULL FOR INSERT ONLY is equivalent to DEFAULT ON NULL +SQL> -- So this also raises an ORA-01407 error +SQL> update default_values + 2 set c3 = null; +set c3 = null + * +ERROR at line 2: +ORA-01407: cannot update ("CHRIS"."DEFAULT_VALUES"."C3") to NULL + + +SQL> +SQL> -- C4 is DEFAULT ON NULL FOR INSERT AND UPDATE +SQL> -- So the database replaces NULL with its default value +SQL> update default_values + 2 set c4 = null; + +1 row updated. + +SQL> +SQL> -- The value of C4 has changed; all other columns retain their INSERT value +SQL> select * from default_values; + + ID C1 C2 C3 C4 +---------- ---------- ---------- ---------- ---------- + 1 1.585189 1.585189 1.608401 +---- + +== Benefits + +Providing a default value for `NULL` on `UPDATE` simplifies code to map `NULL` to a non `NULL` value when changing data. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/CREATE-TABLE.html#GUID-F9CE0CC3-13AE-4744-A43C-EAC7A71AAAB6__CJABFBAA[CREATE TABLE Documentation] diff --git a/features/fuzzy-match-operator.adoc b/features/fuzzy-match-operator.adoc new file mode 100644 index 0000000..fe53e92 --- /dev/null +++ b/features/fuzzy-match-operator.adoc @@ -0,0 +1,124 @@ += FUZZY_MATCH operator +:database-version: 23.2 +:database-category: sql + +[[feature_summary]] + +The `FUZZY_MATCH` operator enables you to compare strings for similarity using algorithms such as Jaro-Winkler and Levenshtein distance. + +[source,sql] +[subs="verbatim"] +---- +/* Compare the team names to "Champions City" with the different fuzzy matching algorithms */ +with teams as ( + select * from ( + values ( 'Champions United' ), + ( 'Runner-up City' ), + ( 'Midtable Town' ), + ( 'Underdogs United' ), + ( 'Upstart FC' ), + ( 'Relegated Athletic' ) + ) t ( team_name ) +), match_value as ( + select 'Champions City' match_team +) + select team_name, match_team, + fuzzy_match ( levenshtein, team_name, match_team ) as levenshtein, + fuzzy_match ( jaro_winkler, team_name, match_team ) as jaro_winkler, + fuzzy_match ( bigram, team_name, match_team ) as bigram, + fuzzy_match ( trigram, team_name, match_team ) as trigram, + fuzzy_match ( whole_word_match, team_name, match_team ) as wwm, + fuzzy_match ( longest_common_substring, team_name, match_team ) as lcs + from teams + cross join match_value; + + +/* Find the team names that match "Champions City" with Jaro-Winkler score > 90 */ +with teams as ( + select * from ( + values ( 'Champions United' ), + ( 'Runner-up City' ), + ( 'Midtable Town' ), + ( 'Underdogs United' ), + ( 'Upstart FC' ), + ( 'Relegated Athletic' ) + ) t ( team_name ) +), match_value as ( + select 'Champions City' match_team +) + select team_name, match_team + from teams + join match_value + on fuzzy_match ( jaro_winkler, team_name, match_team ) > 90; +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> /* Compare the team names to "Champions City" for the different fuzzy matching algorithms */ +SQL> with teams as ( + 2 select * from ( + 3 values ( 'Champions United' ), + 4 ( 'Runner-up City' ), + 5 ( 'Midtable Town' ), + 6 ( 'Underdogs United' ), + 7 ( 'Upstart FC' ), + 8 ( 'Relegated Athletic' ) + 9 ) t ( team_name ) + 10 ), match_value as ( + 11 select 'Champions City' match_team + 12 ) + 13 select team_name, match_team, + 14 fuzzy_match ( levenshtein, team_name, match_team ) as levenshtein, + 15 fuzzy_match ( jaro_winkler, team_name, match_team ) as jaro_winkler, + 16 fuzzy_match ( bigram, team_name, match_team ) as bigram, + 17 fuzzy_match ( trigram, team_name, match_team ) as trigram, + 18 fuzzy_match ( whole_word_match, team_name, match_team ) as wwm, + 19 fuzzy_match ( longest_common_substring, team_name, match_team ) as lcs + 20 from teams + 21 cross join match_value; + +TEAM_NAME MATCH_TEAM LEVENSHTEIN JARO_WINKLER BIGRAM TRIGRAM WWM LCS +------------------ -------------- ----------- ------------ ---------- ---------- ---------- ---------- +Champions United Champions City 75 92 66 57 50 62 +Runner-up City Champions City 36 57 30 25 50 35 +Midtable Town Champions City 8 44 0 0 0 7 +Underdogs United Champions City 32 49 13 0 0 12 +Upstart FC Champions City 8 56 0 0 0 7 +Relegated Athletic Champions City 12 41 0 0 0 5 + +6 rows selected. + +SQL> +SQL> /* Find the team names that match "Champions City" with Jaro-Winkler score > 90 */ +SQL> with teams as ( + 2 select * from ( + 3 values ( 'Champions United' ), + 4 ( 'Runner-up City' ), + 5 ( 'Midtable Town' ), + 6 ( 'Underdogs United' ), + 7 ( 'Upstart FC' ), + 8 ( 'Relegated Athletic' ) + 9 ) t ( team_name ) + 10 ), match_value as ( + 11 select 'Champions City' match_team + 12 ) + 13 select team_name, match_team + 14 from teams + 15 join match_value + 16 on fuzzy_match ( jaro_winkler, team_name, match_team ) > 90; + +TEAM_NAME MATCH_TEAM +------------------ -------------- +Champions United Champions City +---- + +== Benefits + +This operator makes it easier to find similar strings with SQL. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/data-quality-operators.html#GUID-C13A179C-1F82-4522-98AA-E21C6504755E[FUZZY_MATCH Documentation] diff --git a/features/json-plsql-type-conversions.adoc b/features/json-plsql-type-conversions.adoc new file mode 100644 index 0000000..6ff690a --- /dev/null +++ b/features/json-plsql-type-conversions.adoc @@ -0,0 +1,121 @@ += PL/SQL and JSON type conversions +:database-version: 23.2 +:database-category: plsql + +[[feature_summary]] + +The `JSON` constructor can now accept a PL/SQL array or record type and return a JSON object or array populated with the aggregate type data. Conversely, the built-in function `json_value` now supports PL/SQL array and record types in the `RETURNING` clause, mapping from JSON to the specified aggregate type. + +[source,sql] +[subs="verbatim"] +---- +declare + type money_rec is record ( + currency_code char(3), + amount number + ); + + type country_price_arr is table of money_rec + index by varchar2(2); + + country_prices country_price_arr; + price_json json; +begin + country_prices := country_price_arr ( + 'US' => money_rec ( 'USD', 9.99 ), + 'GB' => money_rec ( 'GBP', 8.99 ), + 'DE' => money_rec ( 'EUR', 8.99 ), + 'IN' => money_rec ( 'INR', 849 ) + ); + + /* Automatically convert PL/SQL types to JSON by passing to JSON constructor */ + price_json := json ( country_prices ); + + dbms_output.put_line ( json_serialize ( price_json returning clob pretty ) ); + + for country, price in pairs of + /* Convert JSON to PL/SQL types with JSON_value */ + json_value ( price_json, '$' returning country_price_arr ) + loop + dbms_output.put_line ( + country || ' = ' || price.currency_code || to_char ( price.amount, '990.00' ) + ); + end loop; +end; +/ +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> declare + 2 type money_rec is record ( + 3 currency_code char(3), + 4 amount number + 5 ); + 6 + 7 type country_price_arr is table of money_rec + 8 index by varchar2(2); + 9 + 10 country_prices country_price_arr; + 11 price_json json; + 12 begin + 13 country_prices := country_price_arr ( + 14 'US' => money_rec ( 'USD', 9.99 ), + 15 'GB' => money_rec ( 'GBP', 8.99 ), + 16 'DE' => money_rec ( 'EUR', 8.99 ), + 17 'IN' => money_rec ( 'INR', 849 ) + 18 ); + 19 + 20 /* Automatically convert PL/SQL types to JSON by passing to JSON constructor */ + 21 price_json := json ( country_prices ); + 22 + 23 dbms_output.put_line ( json_serialize ( price_json returning clob pretty ) ); + 24 + 25 for country, price in pairs of + 26 /* Convert JSON to PL/SQL types with JSON_value */ + 27 json_value ( price_json, '$' returning country_price_arr ) + 28 loop + 29 dbms_output.put_line ( + 30 country || ' = ' || price.currency_code || to_char ( price.amount, '990.00' ) + 31 ); + 32 end loop; + 33 end; + 34 / +{ + "DE" : + { + "CURRENCY_CODE" : "EUR", + "AMOUNT" : 8.99 + }, + "GB" : + { + "CURRENCY_CODE" : "GBP", + "AMOUNT" : 8.99 + }, + "IN" : + { + "CURRENCY_CODE" : "INR", + "AMOUNT" : 849 + }, + "US" : + { + "CURRENCY_CODE" : "USD", + "AMOUNT" : 9.99 + } +} +DE = EUR 8.99 +GB = GBP 8.99 +IN = INR 849.00 +US = USD 9.99 +---- + +== Benefits + +PL/SQL to JSON type mappings enables you to convert JSON to PL/SQL types and back using built-in functions. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/lnpls/plsql-data-types.html#GUID-4B5AE6EE-6762-4125-A44F-73EFA4B37526[PL/SQL and JSON Type Conversions Documentation] diff --git a/features/phonic-encode-operator.adoc b/features/phonic-encode-operator.adoc new file mode 100644 index 0000000..3b4af84 --- /dev/null +++ b/features/phonic-encode-operator.adoc @@ -0,0 +1,78 @@ += PHONIC_ENCODE operator +:database-version: 23.2 +:database-category: sql + +[[feature_summary]] + +The `PHONIC_ENCODE` operator indexes words according to their English pronunciation using the metaphone or double metaphone algorithms. + +[source,sql] +[subs="verbatim"] +---- +/* Get the phonic encoding of the team names + The third parameter is the number of characters in the encoded string */ +with teams as ( + select * from ( + values ( 'Champions United' ), + ( 'Runner-up City' ), + ( 'Midtable Town' ), + ( 'Underdogs United' ), + ( 'Upstart FC' ), + ( 'Relegated Athletic' ) + ) t ( team_name ) +) + select team_name, + phonic_encode ( double_metaphone, team_name, 1 ) as team_name_dm1, + phonic_encode ( double_metaphone_alt, team_name, 1 ) as team_name_dm1_alt, + phonic_encode ( double_metaphone, team_name, 6 ) as team_name_dm6, + phonic_encode ( double_metaphone_alt, team_name, 6 ) as team_name_dm6_alt, + phonic_encode ( double_metaphone, team_name, 12 ) as team_name_dm12, + phonic_encode ( double_metaphone_alt, team_name, 12 ) as team_name_dm12_alt + from teams; +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> /* Get the phonic encoding of the team names +SQL> The third parameter is the number of characters in the encoded string */ +SQL> with teams as ( + 2 select * from ( + 3 values ( 'Champions United' ), + 4 ( 'Runner-up City' ), + 5 ( 'Midtable Town' ), + 6 ( 'Underdogs United' ), + 7 ( 'Upstart FC' ), + 8 ( 'Relegated Athletic' ) + 9 ) t ( team_name ) + 10 ) + 11 select team_name, + 12 phonic_encode ( double_metaphone, team_name, 1 ) as team_name_dm1, + 13 phonic_encode ( double_metaphone_alt, team_name, 1 ) as team_name_dm1_alt, + 14 phonic_encode ( double_metaphone, team_name, 6 ) as team_name_dm6, + 15 phonic_encode ( double_metaphone_alt, team_name, 6 ) as team_name_dm6_alt, + 16 phonic_encode ( double_metaphone, team_name, 12 ) as team_name_dm12, + 17 phonic_encode ( double_metaphone_alt, team_name, 12 ) as team_name_dm12_alt + 18 from teams; + +TEAM_NAME TEAM_NAME_DM1 TEAM_NAME_DM1_ALT TEAM_NAME_DM6 TEAM_NAME_DM6_ALT TEAM_NAME_DM12 TEAM_NAME_DM12_ALT +------------------ ------------------------- ------------------------- ------------------------- ------------------------- ------------------------- ------------------------- +Champions United X X XMPNSN XMPNSN XMPNSNTT XMPNSNTT +Runner-up City R R RNRPST RNRPST RNRPST RNRPST +Midtable Town M M MTPLTN MTPLTN MTPLTN MTPLTN +Underdogs United A A ANTRTK ANTRTK ANTRTKSNTT ANTRTKSNTT +Upstart FC A A APSTRT APSTRT APSTRTFK APSTRTFK +Relegated Athletic R R RLKTT0 RLKTTT RLKTT0LTK RLKTTTLTK + +6 rows selected. +---- + +== Benefits + +The `PHONIC_ENCODE` operator enables you to run data quality queries, comparing text based on how it's spoken. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/data-quality-operators.html#GUID-4D870366-C06F-4E63-BE15-609C1F2A96D3[PHONIC_ENCODE Documentation] diff --git a/features/schema-level-privileges.adoc b/features/schema-level-privileges.adoc new file mode 100644 index 0000000..66fe784 --- /dev/null +++ b/features/schema-level-privileges.adoc @@ -0,0 +1,80 @@ += Schema Level Privileges +:database-version: 23.2 +:database-category: sql + +[[feature_summary]] + +Schema privileges enable you to grant a user access to every object of the specified type in another schema. For example, to allow one user to query every table in another schema. + +[source,sql] +[subs="verbatim"] +---- +-- create user to own tables +create user data_owner + no authentication; + +-- create user to query the tables +grant create session to reporting_user + identified by reporting_user; + +-- This gives reporting_user query privileges on every current & future table owned by data_owner +grant read any table + on schema data_owner + to reporting_user; + +-- reporting_user automatically gets access to this table +create table data_owner.tab ( c1 int ); + +conn reporting_user/reporting_user@23cfree + +select count(*) from data_owner.tab; +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> create user data_owner + 2 no authentication; + +User DATA_OWNER created. + +SQL> +SQL> -- create user to query the tables +SQL> grant create session to reporting_user + 2 identified by reporting_user; + +Grant succeeded. + +SQL> +SQL> -- This gives reporting_user query privileges on every current & future table owned by data_owner +SQL> grant read any table + 2 on schema data_owner + 3 to reporting_user; + +Grant succeeded. + +SQL> +SQL> -- reporting_user automatically gets access to this table +SQL> create table data_owner.tab ( c1 int ); + +Table DATA_OWNER.TAB created. + +SQL> conn reporting_user/reporting_user@23cfree +Connected. +SQL> +SQL> select count(*) from data_owner.tab; + + COUNT(*) +---------- + 0 +---- + +== Benefits + +Schema privileges simplify data access controls. + +== Further information + +* Availability: All Offerings +* link:https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/GRANT.html#GUID-20B4E2C0-A7F8-4BC8-A5E8-BE61BDC41AC3[GRANT Documentation] diff --git a/features/sql-transpiler.adoc b/features/sql-transpiler.adoc new file mode 100644 index 0000000..e48ed3e --- /dev/null +++ b/features/sql-transpiler.adoc @@ -0,0 +1,201 @@ += SQL Transpiler +:database-version: 23.2 +:database-category: sql plsql + +[[feature_summary]] + +The SQL Transpiler automatically and wherever possible converts (transpiles) PL/SQL functions within SQL into SQL expressions, without user intervention. + +[source,sql] +[subs="verbatim"] +---- +create table employees ( + employee_id integer primary key, + first_name varchar2(100), + last_name varchar2(100), + hire_date date +); + +insert into employees (employee_id,first_name,last_name,hire_date) +values (100,'Steven','King',to_date('17-JUN-2013 00:00','DD-MON-YYYY HH24:MI')), + (101,'Neena','Yang',to_date('21-SEP-2015 00:00','DD-MON-YYYY HH24:MI')), + (102,'Lex','Garcia',to_date('13-JAN-2011 00:00','DD-MON-YYYY HH24:MI')), + (103,'Alexander','James',to_date('03-JAN-2016 00:00','DD-MON-YYYY HH24:MI')), + (104,'Bruce','Miller',to_date('21-MAY-2017 00:00','DD-MON-YYYY HH24:MI')), + (105,'David','Williams',to_date('25-JUN-2015 00:00','DD-MON-YYYY HH24:MI')), + (106,'Valli','Jackson',to_date('05-FEB-2016 00:00','DD-MON-YYYY HH24:MI')), + (107,'Diana','Nguyen',to_date('07-FEB-2017 00:00','DD-MON-YYYY HH24:MI')), + (108,'Nancy','Gruenberg',to_date('17-AUG-2012 00:00','DD-MON-YYYY HH24:MI')), + (109,'Daniel','Faviet',to_date('16-AUG-2012 00:00','DD-MON-YYYY HH24:MI')), + (110,'John','Chen',to_date('28-SEP-2015 00:00','DD-MON-YYYY HH24:MI')); + + +create or replace function get_year ( dt date ) + return number as +begin + return extract ( year from dt ); +end get_year; +/ + +set serveroutput off +-- This disables the transpiler; it is disabled by default +alter session set sql_transpiler = 'OFF'; + +select count (*) from employees +where get_year ( hire_date ) = 2015; + +-- With the transpiler disabled, the predicate is the function call GET_YEAR +select * +from dbms_xplan.display_cursor( format => 'BASIC LAST +PREDICATE'); + +-- Enable the automatic SQL transpiler +alter session set sql_transpiler = 'ON'; + +-- With the transpiler enabled, the expression in the function is extracted +-- the predicate is now EXTRACT(YEAR FROM INTERNAL_FUNCTION("HIRE_DATE")) +-- => no SQL <> PL/SQL runtime context switch +select count (*) from employees +where get_year ( hire_date ) = 2017; + +select * +from dbms_xplan.display_cursor( format => 'BASIC LAST +PREDICATE'); +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> create table employees ( + 2 employee_id integer primary key, + 3 first_name varchar2(100), + 4 last_name varchar2(100), + 5 hire_date date + 6 ); + +Table EMPLOYEES created. + +SQL> +SQL> insert into employees (employee_id,first_name,last_name,hire_date) + 2 values (100,'Steven','King',to_date('17-JUN-2013 00:00','DD-MON-YYYY HH24:MI')), + 3 (101,'Neena','Yang',to_date('21-SEP-2015 00:00','DD-MON-YYYY HH24:MI')), + 4 (102,'Lex','Garcia',to_date('13-JAN-2011 00:00','DD-MON-YYYY HH24:MI')), + 5 (103,'Alexander','James',to_date('03-JAN-2016 00:00','DD-MON-YYYY HH24:MI')), + 6 (104,'Bruce','Miller',to_date('21-MAY-2017 00:00','DD-MON-YYYY HH24:MI')), + 7 (105,'David','Williams',to_date('25-JUN-2015 00:00','DD-MON-YYYY HH24:MI')), + 8 (106,'Valli','Jackson',to_date('05-FEB-2016 00:00','DD-MON-YYYY HH24:MI')), + 9 (107,'Diana','Nguyen',to_date('07-FEB-2017 00:00','DD-MON-YYYY HH24:MI')), + 10 (108,'Nancy','Gruenberg',to_date('17-AUG-2012 00:00','DD-MON-YYYY HH24:MI')), + 11 (109,'Daniel','Faviet',to_date('16-AUG-2012 00:00','DD-MON-YYYY HH24:MI')), + 12 (110,'John','Chen',to_date('28-SEP-2015 00:00','DD-MON-YYYY HH24:MI')); + +11 rows inserted. + +SQL> +SQL> +SQL> create or replace function get_year ( dt date ) + 2 return number as + 3 begin + 4 return extract ( year from dt ); + 5 end get_year; + 6 / + +Function GET_YEAR compiled + +SQL> +SQL> set serveroutput off +SQL> -- This disables the transpiler; it is disabled by default +SQL> alter session set sql_transpiler = 'OFF'; + +Session altered. + +SQL> +SQL> select count (*) from employees + 2 where get_year ( hire_date ) = 2015; + + COUNT(*) +---------- + 3 + +SQL> +SQL> -- With the transpiler disabled, the predicate is the function call GET_YEAR +SQL> select * + 2 from dbms_xplan.display_cursor( format => 'BASIC LAST +PREDICATE'); + +PLAN_TABLE_OUTPUT +---------------------------------------------------------------------------- +EXPLAINED SQL STATEMENT: +------------------------ +select count (*) from employees where get_year ( hire_date ) = 2015 + +Plan hash value: 1756381138 + +---------------------------------------- +| Id | Operation | Name | +---------------------------------------- +| 0 | SELECT STATEMENT | | +| 1 | SORT AGGREGATE | | +|* 2 | TABLE ACCESS FULL| EMPLOYEES | +---------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 2 - filter("GET_YEAR"("HIRE_DATE")=2015) + + +19 rows selected. + +SQL> +SQL> -- Enable the automatic SQL transpiler +SQL> alter session set sql_transpiler = 'ON'; + +Session altered. + +SQL> +SQL> -- With the transpiler enabled, the expression in the function is extracted +SQL> -- the predicate is now EXTRACT(YEAR FROM INTERNAL_FUNCTION("HIRE_DATE")) +SQL> -- => no SQL <> PL/SQL runtime context switch +SQL> select count (*) from employees + 2 where get_year ( hire_date ) = 2017; + + COUNT(*) +---------- + 2 + +SQL> +SQL> select * + 2 from dbms_xplan.display_cursor( format => 'BASIC LAST +PREDICATE'); + +PLAN_TABLE_OUTPUT +-------------------------------------------------------------------------- +EXPLAINED SQL STATEMENT: +------------------------ +select count (*) from employees where get_year ( hire_date ) = 2017 + +Plan hash value: 1756381138 + +---------------------------------------- +| Id | Operation | Name | +---------------------------------------- +| 0 | SELECT STATEMENT | | +| 1 | SORT AGGREGATE | | +|* 2 | TABLE ACCESS FULL| EMPLOYEES | +---------------------------------------- + +Predicate Information (identified by operation id): +--------------------------------------------------- + + 2 - filter(EXTRACT(YEAR FROM INTERNAL_FUNCTION("HIRE_DATE"))=2017) + + +19 rows selected. +---- + +== Benefits + +The conversion operation is transparent to users and can improve performance by reducing overhead accrued from switching between the SQL and PL/SQL runtime. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/tgsql/introduction-to-sql-tuning.html#GUID-C25CC846-7515-4527-8345-DAE2896EDAC8[SQL Tuning Guide] diff --git a/features/sum-and-avg-over-interval-types.adoc b/features/sum-and-avg-over-interval-types.adoc new file mode 100644 index 0000000..5c9c4ea --- /dev/null +++ b/features/sum-and-avg-over-interval-types.adoc @@ -0,0 +1,46 @@ += SUM and AVG over INTERVAL data types +:database-version: 23.2 +:database-category: sql + +[[feature_summary]] + +You can pass `INTERVAL` datatypes to the `SUM` and `AVG` aggregate and analytic functions. + +[source,sql] +[subs="verbatim"] +---- +with rws as ( + select interval '0' hour + numtodsinterval ( level, 'hour' ) dsi + connect by level <= 10 +) + select sum ( dsi ) total_duration, + avg ( dsi ) mean_duration + from rws; +---- + +.Result +[source,sql] +[subs="verbatim"] +---- +SQL> with rws as ( + 2 select interval '0' hour + numtodsinterval ( level, 'hour' ) dsi + 3 connect by level <= 10 + 4 ) + 5 select sum ( dsi ) total_duration, + 6 avg ( dsi ) mean_duration + 7 from rws; + +TOTAL_DURATION MEAN_DURATION +------------------- ------------------- ++02 07:00:00.000000 +00 05:30:00.000000 +---- + +== Benefits + +This enhancement makes it easier for developers to calculate totals and averages over `INTERVAL` values. + +== Further information + +* Availability: All Offerings +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/AVG.html#GUID-B64BCBF1-DAA0-4D88-9821-2C4D3FDE5E4A[AVG Documentation] +* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/SUM.html#GUID-5610BE2C-CFE5-446F-A1F7-B924B5663220[SUM Documentation]