Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
73 changes: 73 additions & 0 deletions features/ceil-floor-round-for-datetime-types.adoc
Original file line number Diff line number Diff line change
@@ -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]
130 changes: 130 additions & 0 deletions features/default-on-null-update.adoc
Original file line number Diff line number Diff line change
@@ -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 <null> 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 <null> 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]
124 changes: 124 additions & 0 deletions features/fuzzy-match-operator.adoc
Original file line number Diff line number Diff line change
@@ -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]
Loading