Compute
Elastic Cloud Server
Huawei Cloud Flexus
Bare Metal Server
Auto Scaling
Image Management Service
Dedicated Host
FunctionGraph
Cloud Phone Host
Huawei Cloud EulerOS
Networking
Virtual Private Cloud
Elastic IP
Elastic Load Balance
NAT Gateway
Direct Connect
Virtual Private Network
VPC Endpoint
Cloud Connect
Enterprise Router
Enterprise Switch
Global Accelerator
Management & Governance
Cloud Eye
Identity and Access Management
Cloud Trace Service
Resource Formation Service
Tag Management Service
Log Tank Service
Config
OneAccess
Resource Access Manager
Simple Message Notification
Application Performance Management
Application Operations Management
Organizations
Optimization Advisor
IAM Identity Center
Cloud Operations Center
Resource Governance Center
Migration
Server Migration Service
Object Storage Migration Service
Cloud Data Migration
Migration Center
Cloud Ecosystem
KooGallery
Partner Center
User Support
My Account
Billing Center
Cost Center
Resource Center
Enterprise Management
Service Tickets
HUAWEI CLOUD (International) FAQs
ICP Filing
Support Plans
My Credentials
Customer Operation Capabilities
Partner Support Plans
Professional Services
Analytics
MapReduce Service
Data Lake Insight
CloudTable Service
Cloud Search Service
Data Lake Visualization
Data Ingestion Service
GaussDB(DWS)
DataArts Studio
Data Lake Factory
DataArts Lake Formation
IoT
IoT Device Access
Others
Product Pricing Details
System Permissions
Console Quick Start
Common FAQs
Instructions for Associating with a HUAWEI CLOUD Partner
Message Center
Security & Compliance
Security Technologies and Applications
Web Application Firewall
Host Security Service
Cloud Firewall
SecMaster
Anti-DDoS Service
Data Encryption Workshop
Database Security Service
Cloud Bastion Host
Data Security Center
Cloud Certificate Manager
Edge Security
Managed Threat Detection
Blockchain
Blockchain Service
Web3 Node Engine Service
Media Services
Media Processing Center
Video On Demand
Live
SparkRTC
MetaStudio
Storage
Object Storage Service
Elastic Volume Service
Cloud Backup and Recovery
Storage Disaster Recovery Service
Scalable File Service Turbo
Scalable File Service
Volume Backup Service
Cloud Server Backup Service
Data Express Service
Dedicated Distributed Storage Service
Containers
Cloud Container Engine
SoftWare Repository for Container
Application Service Mesh
Ubiquitous Cloud Native Service
Cloud Container Instance
Databases
Relational Database Service
Document Database Service
Data Admin Service
Data Replication Service
GeminiDB
GaussDB
Distributed Database Middleware
Database and Application Migration UGO
TaurusDB
Middleware
Distributed Cache Service
API Gateway
Distributed Message Service for Kafka
Distributed Message Service for RabbitMQ
Distributed Message Service for RocketMQ
Cloud Service Engine
Multi-Site High Availability Service
EventGrid
Dedicated Cloud
Dedicated Computing Cluster
Business Applications
Workspace
ROMA Connect
Message & SMS
Domain Name Service
Edge Data Center Management
Meeting
AI
Face Recognition Service
Graph Engine Service
Content Moderation
Image Recognition
Optical Character Recognition
ModelArts
ImageSearch
Conversational Bot Service
Speech Interaction Service
Huawei HiLens
Video Intelligent Analysis Service
Developer Tools
SDK Developer Guide
API Request Signing Guide
Terraform
Koo Command Line Interface
Content Delivery & Edge Computing
Content Delivery Network
Intelligent EdgeFabric
CloudPond
Intelligent EdgeCloud
Solutions
SAP Cloud
High Performance Computing
Developer Services
ServiceStage
CodeArts
CodeArts PerfTest
CodeArts Req
CodeArts Pipeline
CodeArts Build
CodeArts Deploy
CodeArts Artifact
CodeArts TestPlan
CodeArts Check
CodeArts Repo
Cloud Application Engine
MacroVerse aPaaS
KooMessage
KooPhone
KooDrive
On this page

Show all

User-defined Subtypes

Updated on 2024-06-03 GMT+08:00

In PL/SQL, SUBTYPE can be used to create its own subtypes. The base type can be any basic type or user-defined type. Subtypes can provide data type compatibility, display the intended use of data items of that type, and detect values that are out of range.

The basic definition syntax of SUBTYPE is as follows:

SUBTYPE subtype_name IS base_type  [ { ( precision [, scale ] ) | RANGE low_value .. high_value } ] [ NOT NULL ]

Parameters:

  • SUBTYPE: SUBTYPE keyword.
  • subtype_name: name of the subtype to be defined.
  • base_type: base type, which can be the base type or user-defined type based on which the subtype is created.
  • precision [, scale ]: typmod constraints that can be added.
  • RANGE low_value .. high_value: range constraints that can be added.
  • NOT NULL: NOT NULL constraints that can be added.
NOTE:
  • base_type supports basic types, user-defined data types, and subtypes.
  • If the typmod constraint is specified, when a value is assigned to a variable of the SUBTYPE type, the system checks whether the value complies with the typmod constraint and whether the specified typmod constraint can be consistent with the base type.
  • Range constraints can be specified only for the int types, including TINYINT, SMALLINT, MEDIUMINT, INTEGER, BINARY_INTEGER, BIGINT, and INT. If the range constraints are specified, the system checks whether the value is within the specified range when assigning a value to a subtype variable.
  • The upper and lower limits of RANGE cannot exceed INT64.
  • Currently, the RANGE constraints cannot be used when a variable is created.
  • The constraint status is updated when the SUBTYPE type is nested or a variable of the SUBTYPE type is created.
  • If NOT NULL is specified, variables of the SUBTYPE type must be initialized and cannot be assigned NULL values.
  • The SUBTYPE type can be used as the input and output parameter types of stored procedures.
  • Subtype variables can be specified using %type and %rowtype. %type supports all base types, and %rowtype supports tables but does not support sets.
  • Subtypes support base type constructors.
  • The specified character set is not supported.
  • This command can be used only in A-compatible database.
  • If a database is upgraded from a version that does not support subtypes to a version that supports subtypes and the upgrade is not committed, subtypes cannot be used.

Example 1: An unconstrained subtype is used.

gaussdb=# DECLARE
     SUBTYPE sint IS INT;
     a sint := 2147483647;
 BEGIN
     DBE_OUTPUT.PUT_LINE('a = ' || a);
 END;
 /
a = 2147483647
ANONYMOUS BLOCK EXECUTE

Example 2: Subtypes support typmod, range, and NOT NULL constraints.

-- typmod constraint
gaussdb=# DECLARE
     SUBTYPE sdec IS DECIMAL(3,2) NOT NULL;
     a sdec := 1.1;
     b sdec(5,2) := 322.1;
 BEGIN
     DBE_OUTPUT.PUT_LINE('a = ' || a);
     DBE_OUTPUT.PUT_LINE('b = ' || b);
 END;
 /
a = 1.10
b = 322.10
ANONYMOUS BLOCK EXECUTE
-- NOT NULL constraint
gaussdb=# DECLARE
     SUBTYPE sint IS INT NOT NULL;
     a sint;
 BEGIN
     NULL;
 END;
 /
ERROR:  variables declared as NOT NULL must have a default value.
CONTEXT:  compilation of PL/pgSQL function "inline_code_block" near line 2
gaussdb=# DECLARE
     SUBTYPE age IS BINARY_INTEGER RANGE 0..100 NOT NULL;
     a age := 18;
     b age := 20;
 BEGIN
     DBE_OUTPUT.PUT_LINE('Age of a:' || a);
     DBE_OUTPUT.PUT_LINE('Age of b:' || b);
 END;
 /
Age of a: 18
Age of b: 20
ANONYMOUS BLOCK EXECUTE

Example 3: Subtypes nest user-defined data types and use the base type constructor.

gaussdb=# DECLARE
     TYPE arrint IS VARRAY(10) OF INTEGER;
     SUBTYPE sarrint IS arrint;
     -- a sarrint := sarrint(1,2,3,4): An error is reported. Only the base type constructor is supported.
     a sarrint := arrint(1,2,3,4);
 BEGIN
     FOR i IN 1..4 LOOP
         DBE_OUTPUT.PUT_LINE(a(i));
     END LOOP;
 END;
 /
1
2
3
4
ANONYMOUS BLOCK EXECUTE

Example 4: Subtypes support self-nesting, and the constraint condition is updated.

-- range constraint
gaussdb=# DECLARE
     SUBTYPE sint IS INTEGER RANGE 10..99;
     SUBTYPE ssint IS sint RANGE 0..9;
     a sint := 50;
     b ssint := 5;
 BEGIN
     DBE_OUTPUT.PUT_LINE('a = ' || a);
     DBE_OUTPUT.PUT_LINE('b = ' || b);
 END;
 /
a = 50
b = 5
ANONYMOUS BLOCK EXECUTE
-- typmod constraint
gaussdb=# DECLARE
     SUBTYPE word IS VARCHAR2(5);
     SUBTYPE sentence IS word(50);
     a word := 'Tom';
     b sentence := 'Tom and Jerry';
     c sentence(8) := 'Mountain';
 BEGIN
     DBE_OUTPUT.PUT_LINE('a = ' || a);
     DBE_OUTPUT.PUT_LINE('b = ' || b);
     DBE_OUTPUT.PUT_LINE('c = ' || c);
 END;
 /
a = Tom
b = Tom and Jerry
c = Mountain
ANONYMOUS BLOCK EXECUTE

Example 5: User-defined data types nest subtypes.

gaussdb=# DECLARE
     SUBTYPE sint IS BINARY_INTEGER RANGE 0..99;
     TYPE tabint IS TABLE OF sint;
     a tabint := tabint();
 BEGIN
     a.EXTEND(10);
     a(1) := 50;
 END;
 /
ANONYMOUS BLOCK EXECUTE

We use cookies to improve our site and your experience. By continuing to browse our site you accept our cookie policy. Find out more

Feedback

Feedback

Feedback

0/500

Selected Content

Submit selected content with the feedback