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

Pseudocolumn

Updated on 2024-08-20 GMT+08:00
ROWNUM is a pseudocolumn that returns a number indicating the row number of the obtained query result. The value of ROWNUM in the first row is 1, the value of ROWNUM in the second row is 2, and so on. ROWNUM can be used to limit the number of rows returned by a query, as shown in the following example:
 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
gaussdb=# CREATE TABLE Students (name varchar(20), id int) with (STORAGE_TYPE = USTORE);
gaussdb=# INSERT INTO Students VALUES ('Jack', 35);
gaussdb=# INSERT INTO Students VALUES ('Leon', 15);
gaussdb=# INSERT INTO Students VALUES ('James', 24);
gaussdb=# INSERT INTO Students VALUES ('Taker', 81);
gaussdb=# INSERT INTO Students VALUES ('Mary', 25);
gaussdb=# INSERT INTO Students VALUES ('Rose', 64);
gaussdb=# INSERT INTO Students VALUES ('Perl', 18);
gaussdb=# INSERT INTO Students VALUES ('Under', 57);
gaussdb=# INSERT INTO Students VALUES ('Angel', 101);
gaussdb=# INSERT INTO Students VALUES ('Frank', 20);
gaussdb=# INSERT INTO Students VALUES ('Charlie', 40);

-- Output the first 10 rows of data records in the Students table.
gaussdb=# SELECT * FROM Students WHERE rownum <= 10; 
 name  | id  
-------+-----
 Jack  |  35
 Leon  |  15
 James |  24
 Taker |  81
 Mary  |  25
 Rose  |  64
 Perl  |  18
 Under |  57
 Angel | 101
 Frank |  20
(10 rows)
If the statement has a clause, the output rows are reordered according to the clause.
1
2
3
4
5
6
7
8
gaussdb=# SELECT * FROM Students WHERE rownum < 5 order by 1;
 name  | id
-------+----
 Jack  | 35
 James | 24
 Leon  | 15
 Taker | 81
(4 rows)
If a subquery has a clause but the condition is placed in the outermost query, you can use the ROWNUM condition after sorting.
1
2
3
4
5
6
gaussdb=# SELECT rownum, * FROM (SELECT * FROM Students order by 1) WHERE rownum <= 2;
 rownum |  name   | id
--------+---------+-----
      1 | Angel   | 101
      2 | Charlie |  40
(2 rows)
As long as ROWNUM is greater than a specific positive integer, the condition is always false. As shown in the following example, the statement does not return any result in the table:
1
2
3
4
gaussdb=# SELECT * FROM Students WHERE rownum > 1;
 name | id
------+----
(0 rows)
Use ROWNUM to assign a value to each row within a certain range of the table.
 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
gaussdb=# SELECT * FROM Students;
  name   | id
---------+-----
 Jack    |  35
 Leon    |  15
 James   |  24
 Taker   |  81
 Mary    |  25
 Rose    |  64
 Perl    |  18
 Under   |  57
 Angel   | 101
 Frank   |  20
 Charlie |  40
(11 rows)

gaussdb=# UPDATE Students set id = id + 5 WHERE rownum < 4;
UPDATE 3
gaussdb=# SELECT * FROM Students;
  name   | id
---------+-----
 Jack    |  40
 Leon    |  20
 James   |  29
 Taker   |  81
 Mary    |  25
 Rose    |  64
 Perl    |  18
 Under   |  57
 Angel   | 101
 Frank   |  20
 Charlie |  40
(11 rows)

gaussdb=# DROP TABLE Students;
DROP TABLE
The restrictions on using ROWNUM are as follows:
  • Do not use ROWNUM as an alias to avoid ambiguity in SQL statements.
  • Do not use ROWNUM when creating an index.
  • Do not use ROWNUM as the default value when creating a table.
  • Do not use ROWNUM as an alias in the WHERE clause.
  • Do not use ROWNUM when inserting data.
  • Do not use ROWNUM in a tableless query.
  • Do not use ROWNUM in the LIMIT clause.
  • ROWNUM cannot be used as a parameter of the EXECUTE statement.
  • Do not use ROWNUM to update a clause in the UPSERT statement.
  • If the HAVING clause contains ROWNUM (not in an aggregate function), the GROUP BY clause must also contain ROWNUM (not in an aggregate function), unless the GROUP BY clause contains an expression, for example, SELECT a + a FROM t group by a + a having rownum < 5.
  • If the ROWNUM condition exists in the HAVING clause, the HAVING clause cannot be pushed down to any scan node.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    gaussdb=# CREATE TABLE test (a int, b int);
    CREATE TABLE
    gaussdb=# INSERT INTO test SELECT generate_series, generate_series FROM generate_series(1, 10);
    INSERT 0 10
    
    -- The rownum condition cannot be pushed down to seqscan.
    gaussdb=# EXPLAIN SELECT a,rownum FROM test group by a,rownum having rownum < 5; 
                                 QUERY PLAN                             
    --------------------------------------------------------------------
     HashAggregate  (cost=42.23..69.10 rows=2149 width=4)
       Group By Key: a, ROWNUM
       Filter: ((ROWNUM) < 5)
       ->  Rownum  (cost=0.00..31.49 rows=2149 width=4)
             ->  Seq Scan on test  (cost=0.00..31.49 rows=2149 width=4)
    (5 rows)
    
  • If a subquery contains the ROWNUM condition, the predicate cannot be pushed down to any scan node.
     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    -- b<5 cannot be pushed down to seqscan.
    gaussdb=# EXPLAIN SELECT * FROM (SELECT * FROM test WHERE rownum < 5) WHERE b < 5; 
                                   QUERY PLAN                                
    -------------------------------------------------------------------------
     Subquery Scan on __unnamed_subquery__  (cost=0.00..0.01 rows=1 width=8)
       Filter: (__unnamed_subquery__.b < 5)
       ->  Rownum  (cost=0.00..0.00 rows=1 width=8)
             StopKey: (ROWNUM < 5)
             ->  Seq Scan on test  (cost=0.00..31.49 rows=2149 width=8)
    (5 rows)
    
    gaussdb=# DROP TABLE test;
    DROP TABLE
    
CAUTION:

It is not recommended that the ROWNUM condition be used in the JOIN ON clause. In GaussDB, when the ROWNUM condition is used in the JOIN ON clause, the behavior in the LEFT JOIN, RIGHT JOIN, FULL JOIN, and MERGE INTO scenarios is different from that in other databases, causing risks in service migration.

If the parent query contains the rownum restriction and the projection column of the subquery contains rownum, the restriction is pushed down to the subquery. The constraints are as follows:

  • The parent query can be pushed down only when the rownum restriction condition is <, <=, or = and the subquery directly uses rownum as the pseudocolumn.
  • If the parent query has multiple filter criteria for rownum in the subquery and the pushdown requirements are met, only the first filter criterion is pushed down.
  • If a subquery contains volatile functions and stored procedures, the pushdown is not supported.

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