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
162 changes: 162 additions & 0 deletions features/annotations.adoc
Original file line number Diff line number Diff line change
@@ -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]
75 changes: 75 additions & 0 deletions features/extended-case-controls.adoc
Original file line number Diff line number Diff line change
@@ -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]
Loading