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

How Do I View the Table Permissions of a User?

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

Scenario 1: Run the information_schema.table_privileges command to view the table permissions of a user. Example:

1
SELECT * FROM information_schema.table_privileges WHERE GRANTEE='user_name'; 

Table 1 table_privileges columns

Column

Data Type

Description

grantor

sql_identifier

Permission grantor

grantee

sql_identifier

Permission grantee

table_catalog

sql_identifier

Database where the table is

table_schema

sql_identifier

Schema where the table is

table_name

sql_identifier

Table name

privilege_type

character_data

Type of the granted permission. The value can be SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, ANALYZE, VACUUM, ALTER, DROP, or TRIGGER.

is_grantable

yes_or_no

Indicates if the permission can be granted to other users. YES indicates that the permission can be granted to other users, and NO indicates that the permission cannot be granted to other users.

with_hierarchy

yes_or_no

Indicates if specific operations are allowed to be inherited at the table level. If the specific operation is SELECT, YES is displayed. Otherwise, NO is displayed.

In the preceding figure, user u2 has all permissions of table t2 in schema u2 and the SELECT permission of table t1 in schema u1.

information_schema.table_privileges can query only the permissions directly granted to the user, the has_table_privilege() function can query both directly granted permissions and indirect permissions (obtained by GRANT role to user). For 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
29
30
CREATE TABLE t1 (c1 int);
CREATE USER u1 password '********';
CREATE USER u2 password '********';
GRANT dbadmin to u2; //Indirectly grant permissions through roles.
GRANT SELECT on t1 to u1; // Directly grant the permission.

SET ROLE u1 password '********';
SELECT * FROM public.t1; // Directly grant the permission to access the table.
 c1 
----
(0 rows)

SET ROLE u2 password '********';
SELECT * FROM public.t1; // Indirectly grant the permission to access the table.
 c1 
----
(0 rows)

RESET role; //Switch back to dbadmin.
SELECT * FROM information_schema.table_privileges WHERE table_name = 't1'; // Can only view direct grants.
 grantor |  grantee   | table_catalog | table_schema | table_name | privilege_type | is_grantable | with_hierarchy
---------+------------+---------------+--------------+------------+----------------+--------------+----------------
 dbadmin | u1         | gaussdb       | public       | t1         | SELECT         | NO           | YES
(1 rows)

SELECT has_table_privilege('u2', 'public.t1', 'select'); // Can view both direct and indirect grants.
 has_table_privilege 
---------------------
 t
(1 row)

Scenario 2: To check whether a user has permissions on a table, perform the following steps:

  1. Query the pg_class system catalog.

    1
    SELECT * FROM pg_class WHERE relname = 'tablename';
    

    Check the relacl column. The command output is shown in the following figure. For details about the permission parameters, see Table 2.

    • rolename=xxxx/yyyy: indicates that rolename has the xxxx permission on the table and the permission is obtained from yyyy.
    • =xxxx/yyyy: indicates that public has the xxxx permission on the table and the permission is obtained from yyyy.

    Take the following figure as an example:

    joe=arwdDxtA: indicates that user joe has all permissions (ALL PRIVILEGES).

    leo=arw/joe: indicates that user leo has the read, write, and modify permissions, which are granted by user joe.

    Table 2 Permissions parameters

    Parameter

    Description

    r

    SELECT (read)

    w

    UPDATE (write)

    a

    INSERT (insert)

    d

    DELETE

    D

    TRUNCATE

    x

    REFERENCES

    t

    TRIGGER

    X

    EXECUTE

    U

    USAGE

    C

    CREATE

    c

    CONNECT

    T

    TEMPORARY

    A

    ANALYZE|ANALYSE

    arwdDxtA

    ALL PRIVILEGES (for tables)

    *

    Actions for preceding permissions

  2. You can also use the has_table_privilege function to query user permissions on tables.

    1
    SELECT * FROM has_table_privilege('Username','Table_name', 'select');
    

    For example, query whether user joe has the query permission on table t1.

    1
    SELECT * FROM has_table_privilege('joe','t1','select');
    

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