Starting with Oracle Database 12c Release 2 (12.2), we can now use static expressions* where previously only literal constants were allowed. Here are some examples (also available in this LiveSQL script):
As you can see from this code, static expressions can now be used in subtype declarations.
The definition of static expressions is expanded to include all the PL/SQL scalar types and a much wider range of operators. Character operands are restricted to a safe subset of the ASCII character set. Operators whose results depend on any implicit NLS parameter are disallowed
Expanded and generalized expressions have two primary benefits for PL/SQL developers:
CREATE OR REPLACE PACKAGE pkg
AUTHID DEFINER
IS
c_max_length constant integer := 32767;
SUBTYPE maxvarchar2 IS VARCHAR2 (c_max_length);
END;
/
DECLARE
l_big_string1 VARCHAR2 (pkg.c_max_length) := 'So big....';
l_big_String2 pkg.maxvarchar2 := 'So big via packaged subtype....';
l_half_big VARCHAR2 (pkg.c_max_length / 2) := 'So big....';
BEGIN
DBMS_OUTPUT.PUT_LINE (l_big_string1);
DBMS_OUTPUT.PUT_LINE (l_big_string2);
END;
/
As you can see from this code, static expressions can now be used in subtype declarations.
The definition of static expressions is expanded to include all the PL/SQL scalar types and a much wider range of operators. Character operands are restricted to a safe subset of the ASCII character set. Operators whose results depend on any implicit NLS parameter are disallowed
Expanded and generalized expressions have two primary benefits for PL/SQL developers:
- Programs are much more adaptable to changes in their environment
- Programs are more compact, clearer, and substantially easier to understand and maintain
- the NULL literal
- a character, numeric, or boolean literal
- a reference to a static constant
- a reference to a conditional compilation variable begun with $$
- an operator is allowed in static expressions, if all of its operands are static, and if the operator does not raise an exception when it is evaluated on those operands
Comments
Post a Comment