Skip to content

Commit e683d73

Browse files
Merge pull request #35 from oracle-sql-features/23c-features
More 23c features
2 parents 611e4a9 + 6919bbd commit e683d73

8 files changed

+853
-0
lines changed
Lines changed: 73 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,73 @@
1+
= CEIL, FLOOR, and ROUND for datetime data types
2+
:database-version: 23.2
3+
:database-category: sql
4+
5+
[[feature_summary]]
6+
7+
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.
8+
9+
[source,sql]
10+
[subs="verbatim"]
11+
----
12+
with vals as (
13+
select
14+
interval '+123-5' year(9) to month ymi,
15+
interval '+0 12:34:56' day to second dsi,
16+
to_date ( '12-APR-2023 12:34:56', 'DD-MON-YYYY HH24:MI:SS' ) dt,
17+
to_timestamp ( '12-APR-2023 12:34:56', 'DD-MON-YYYY HH24:MI:SS' ) ts
18+
)
19+
select
20+
-- CEIL rounds up values
21+
ceil ( ymi ) as year_ceil,
22+
ceil ( dsi ) as day_ceil,
23+
ceil ( dt ) as dt_day_ceil,
24+
ceil ( ts ) as ts_day_ceil,
25+
-- FLOOR rounds down the datetime value to the units in the second paramter
26+
floor ( ymi, 'year' ) as ymi_year_floor,
27+
floor ( dsi, 'hh24' ) as dsi_hour_floor,
28+
floor ( dt, 'hh24' ) as dt_hour_floor,
29+
floor ( ts, 'hh24' ) as ts_hour_floor,
30+
-- ROUND now supports INTERVALs
31+
round ( dsi, 'mi' ) as dsi_minute_round
32+
from vals;
33+
----
34+
35+
.Result
36+
[source,sql]
37+
[subs="verbatim"]
38+
----
39+
SQL> with vals as (
40+
2 select
41+
3 interval '+123-5' year(9) to month ymi,
42+
4 interval '+0 12:34:56' day to second dsi,
43+
5 to_date ( '12-APR-2023 12:34:56', 'DD-MON-YYYY HH24:MI:SS' ) dt,
44+
6 to_timestamp ( '12-APR-2023 12:34:56', 'DD-MON-YYYY HH24:MI:SS' ) ts
45+
7 )
46+
8 select
47+
9 -- CEIL rounds up values
48+
10 ceil ( ymi ) as year_ceil,
49+
11 ceil ( dsi ) as day_ceil,
50+
12 ceil ( dt ) as dt_day_ceil,
51+
13 ceil ( ts ) as ts_day_ceil,
52+
14 -- FLOOR rounds down the datetime value to the units in the second paramter
53+
15 floor ( ymi, 'year' ) as ymi_year_floor,
54+
16 floor ( dsi, 'hh24' ) as dsi_hour_floor,
55+
17 floor ( dt, 'hh24' ) as dt_hour_floor,
56+
18 floor ( ts, 'hh24' ) as ts_hour_floor,
57+
19 -- ROUND now supports INTERVALs
58+
20 round ( dsi, 'mi' ) as dsi_minute_round
59+
21 from vals;
60+
61+
YEAR_CE DAY_CEIL DT_DAY_CEIL TS_DAY_CEIL YMI_YEA DSI_HOUR_FLOOR DT_HOUR_FLOOR TS_HOUR_FLOOR DSI_MINUTE_ROUND
62+
------- ------------------- ----------------- ----------------- ------- ------------------- ----------------- ----------------- -------------------
63+
+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
64+
----
65+
66+
== Benefits
67+
68+
These functions make it easy to find the upper and lower bounds for date and time values for a specified unit.
69+
70+
== Further information
71+
72+
* Availability: All Offerings
73+
* 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]
Lines changed: 130 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,130 @@
1+
= Default ON NULL for UPDATE statements
2+
:database-version: 23.2
3+
:database-category: sql
4+
5+
[[feature_summary]]
6+
7+
You can specify a default value when updating a column to `NULL`. The database assigns the default value to the column instead of `NULL`.
8+
9+
[source,sql]
10+
[subs="verbatim"]
11+
----
12+
create table default_values (
13+
id integer,
14+
c1 number default extract ( second from systimestamp ),
15+
c2 number default on null extract ( second from systimestamp ),
16+
c3 number default on null for insert only extract ( second from systimestamp ),
17+
c4 number default on null for insert and update extract ( second from systimestamp )
18+
);
19+
20+
-- For the columns with DEFAULT ON NULL, the database replaces NULL with the timestamp value
21+
insert into default_values
22+
values ( 1, null, null, null, null );
23+
24+
select * from default_values;
25+
26+
-- The standard DEFAULT clause has no impact on UPDATEs, so C1 remains NULL
27+
update default_values
28+
set c1 = null;
29+
30+
-- DEFAULT ON NULL adds an implicit NOT NULL constraint to the column
31+
-- The default only applies on insert, so this raises an ORA-01407 error
32+
update default_values
33+
set c2 = null;
34+
35+
-- DEFAULT ON NULL FOR INSERT ONLY is equivalent to DEFAULT ON NULL
36+
-- So this also raises an ORA-01407 error
37+
update default_values
38+
set c3 = null;
39+
40+
-- C4 is DEFAULT ON NULL FOR INSERT AND UPDATE
41+
-- So the database replaces NULL with its default value
42+
update default_values
43+
set c4 = null;
44+
45+
-- The value of C4 has changed; all other columns retain their INSERT value
46+
select * from default_values;
47+
----
48+
49+
.Result
50+
[source,sql]
51+
[subs="verbatim"]
52+
----
53+
SQL> create table default_values (
54+
2 id integer,
55+
3 c1 number default extract ( second from systimestamp ),
56+
4 c2 number default on null extract ( second from systimestamp ),
57+
5 c3 number default on null for insert only extract ( second from systimestamp ),
58+
6 c4 number default on null for insert and update extract ( second from systimestamp )
59+
7 );
60+
61+
Table created.
62+
63+
SQL>
64+
SQL> -- For the columns with DEFAULT ON NULL, the database replaces NULL with the timestamp value
65+
SQL> insert into default_values
66+
2 values ( 1, null, null, null, null );
67+
68+
1 row created.
69+
70+
SQL>
71+
SQL> select * from default_values;
72+
73+
ID C1 C2 C3 C4
74+
---------- ---------- ---------- ---------- ----------
75+
1 <null> 1.585189 1.585189 1.585189
76+
77+
SQL>
78+
SQL> -- The standard DEFAULT clause has no impact on UPDATEs, so C1 remains NULL
79+
SQL> update default_values
80+
2 set c1 = null;
81+
82+
1 row updated.
83+
84+
SQL>
85+
SQL> -- DEFAULT ON NULL adds an implicit NOT NULL constraint to the column
86+
SQL> -- The default only applies on insert, so this raises an ORA-01407 error
87+
SQL> update default_values
88+
2 set c2 = null;
89+
set c2 = null
90+
*
91+
ERROR at line 2:
92+
ORA-01407: cannot update ("CHRIS"."DEFAULT_VALUES"."C2") to NULL
93+
94+
95+
SQL>
96+
SQL> -- DEFAULT ON NULL FOR INSERT ONLY is equivalent to DEFAULT ON NULL
97+
SQL> -- So this also raises an ORA-01407 error
98+
SQL> update default_values
99+
2 set c3 = null;
100+
set c3 = null
101+
*
102+
ERROR at line 2:
103+
ORA-01407: cannot update ("CHRIS"."DEFAULT_VALUES"."C3") to NULL
104+
105+
106+
SQL>
107+
SQL> -- C4 is DEFAULT ON NULL FOR INSERT AND UPDATE
108+
SQL> -- So the database replaces NULL with its default value
109+
SQL> update default_values
110+
2 set c4 = null;
111+
112+
1 row updated.
113+
114+
SQL>
115+
SQL> -- The value of C4 has changed; all other columns retain their INSERT value
116+
SQL> select * from default_values;
117+
118+
ID C1 C2 C3 C4
119+
---------- ---------- ---------- ---------- ----------
120+
1 <null> 1.585189 1.585189 1.608401
121+
----
122+
123+
== Benefits
124+
125+
Providing a default value for `NULL` on `UPDATE` simplifies code to map `NULL` to a non `NULL` value when changing data.
126+
127+
== Further information
128+
129+
* Availability: All Offerings
130+
* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/CREATE-TABLE.html#GUID-F9CE0CC3-13AE-4744-A43C-EAC7A71AAAB6__CJABFBAA[CREATE TABLE Documentation]

features/fuzzy-match-operator.adoc

Lines changed: 124 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,124 @@
1+
= FUZZY_MATCH operator
2+
:database-version: 23.2
3+
:database-category: sql
4+
5+
[[feature_summary]]
6+
7+
The `FUZZY_MATCH` operator enables you to compare strings for similarity using algorithms such as Jaro-Winkler and Levenshtein distance.
8+
9+
[source,sql]
10+
[subs="verbatim"]
11+
----
12+
/* Compare the team names to "Champions City" with the different fuzzy matching algorithms */
13+
with teams as (
14+
select * from (
15+
values ( 'Champions United' ),
16+
( 'Runner-up City' ),
17+
( 'Midtable Town' ),
18+
( 'Underdogs United' ),
19+
( 'Upstart FC' ),
20+
( 'Relegated Athletic' )
21+
) t ( team_name )
22+
), match_value as (
23+
select 'Champions City' match_team
24+
)
25+
select team_name, match_team,
26+
fuzzy_match ( levenshtein, team_name, match_team ) as levenshtein,
27+
fuzzy_match ( jaro_winkler, team_name, match_team ) as jaro_winkler,
28+
fuzzy_match ( bigram, team_name, match_team ) as bigram,
29+
fuzzy_match ( trigram, team_name, match_team ) as trigram,
30+
fuzzy_match ( whole_word_match, team_name, match_team ) as wwm,
31+
fuzzy_match ( longest_common_substring, team_name, match_team ) as lcs
32+
from teams
33+
cross join match_value;
34+
35+
36+
/* Find the team names that match "Champions City" with Jaro-Winkler score > 90 */
37+
with teams as (
38+
select * from (
39+
values ( 'Champions United' ),
40+
( 'Runner-up City' ),
41+
( 'Midtable Town' ),
42+
( 'Underdogs United' ),
43+
( 'Upstart FC' ),
44+
( 'Relegated Athletic' )
45+
) t ( team_name )
46+
), match_value as (
47+
select 'Champions City' match_team
48+
)
49+
select team_name, match_team
50+
from teams
51+
join match_value
52+
on fuzzy_match ( jaro_winkler, team_name, match_team ) > 90;
53+
----
54+
55+
.Result
56+
[source,sql]
57+
[subs="verbatim"]
58+
----
59+
SQL> /* Compare the team names to "Champions City" for the different fuzzy matching algorithms */
60+
SQL> with teams as (
61+
2 select * from (
62+
3 values ( 'Champions United' ),
63+
4 ( 'Runner-up City' ),
64+
5 ( 'Midtable Town' ),
65+
6 ( 'Underdogs United' ),
66+
7 ( 'Upstart FC' ),
67+
8 ( 'Relegated Athletic' )
68+
9 ) t ( team_name )
69+
10 ), match_value as (
70+
11 select 'Champions City' match_team
71+
12 )
72+
13 select team_name, match_team,
73+
14 fuzzy_match ( levenshtein, team_name, match_team ) as levenshtein,
74+
15 fuzzy_match ( jaro_winkler, team_name, match_team ) as jaro_winkler,
75+
16 fuzzy_match ( bigram, team_name, match_team ) as bigram,
76+
17 fuzzy_match ( trigram, team_name, match_team ) as trigram,
77+
18 fuzzy_match ( whole_word_match, team_name, match_team ) as wwm,
78+
19 fuzzy_match ( longest_common_substring, team_name, match_team ) as lcs
79+
20 from teams
80+
21 cross join match_value;
81+
82+
TEAM_NAME MATCH_TEAM LEVENSHTEIN JARO_WINKLER BIGRAM TRIGRAM WWM LCS
83+
------------------ -------------- ----------- ------------ ---------- ---------- ---------- ----------
84+
Champions United Champions City 75 92 66 57 50 62
85+
Runner-up City Champions City 36 57 30 25 50 35
86+
Midtable Town Champions City 8 44 0 0 0 7
87+
Underdogs United Champions City 32 49 13 0 0 12
88+
Upstart FC Champions City 8 56 0 0 0 7
89+
Relegated Athletic Champions City 12 41 0 0 0 5
90+
91+
6 rows selected.
92+
93+
SQL>
94+
SQL> /* Find the team names that match "Champions City" with Jaro-Winkler score > 90 */
95+
SQL> with teams as (
96+
2 select * from (
97+
3 values ( 'Champions United' ),
98+
4 ( 'Runner-up City' ),
99+
5 ( 'Midtable Town' ),
100+
6 ( 'Underdogs United' ),
101+
7 ( 'Upstart FC' ),
102+
8 ( 'Relegated Athletic' )
103+
9 ) t ( team_name )
104+
10 ), match_value as (
105+
11 select 'Champions City' match_team
106+
12 )
107+
13 select team_name, match_team
108+
14 from teams
109+
15 join match_value
110+
16 on fuzzy_match ( jaro_winkler, team_name, match_team ) > 90;
111+
112+
TEAM_NAME MATCH_TEAM
113+
------------------ --------------
114+
Champions United Champions City
115+
----
116+
117+
== Benefits
118+
119+
This operator makes it easier to find similar strings with SQL.
120+
121+
== Further information
122+
123+
* Availability: All Offerings
124+
* https://docs.oracle.com/en/database/oracle/oracle-database/23/sqlrf/data-quality-operators.html#GUID-C13A179C-1F82-4522-98AA-E21C6504755E[FUZZY_MATCH Documentation]

0 commit comments

Comments
 (0)