Bu sayfa henüz yerel dilinizde mevcut değildir. Daha fazla dil seçeneği eklemek için yoğun bir şekilde çalışıyoruz. Desteğiniz için teşekkür ederiz.

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
Help Center/ GaussDB(DWS)/ Best Practices/ Data Development/ Best Practices of GIN Index

Best Practices of GIN Index

Updated on 2024-10-29 GMT+08:00

A GIN index is a data structure that pairs a key with its posting list. The key indicates a specific value, and the posting list tracks all the locations that this key occurs. For example, 'hello', '14:2 23:4' indicates that hello is found at the locations 14:2 and 23:4. A GIN index efficiently locates tuples with specific keywords, making it ideal for searching elements within multi-valued fields. This section describes how to use GIN indexes to search through array and JSONB types, as well as how to conduct full-text searches.

Using a GIN Index to Search Through the Array Type

Create a GIN index to speed up tag searches.

  1. Create a cluster on the management console. For details, see Creating a DWS 2.0 Cluster.
  2. Use the gsql client to connect to a GaussDB(DWS) database (using the password you defined when creating the cluster).

    1
    gsql -d gaussdb -p 8000 -h 192.168.0.86 -U dbadmin -W password -r
    

    If the following information is displayed, the connection succeeded:

    1
    gaussdb=>
    

  3. Create the books table. The tags column stores the tag information of books using the array type.

    1
    CREATE TABLE books (id SERIAL PRIMARY KEY, title VARCHAR(100), tags TEXT[]);
    

  4. Insert data.

    1
    2
    3
    4
    5
    INSERT INTO books (title, tags) 
    VALUES   ('Book 1', ARRAY['fiction', 'adventure']),
       ('Book 2', ARRAY['science', 'fiction']),
       ('Book 3', ARRAY['romance', 'fantasy']),
       ('Book 4', ARRAY['adventure']);
    

  5. Create a GIN index.

    1
    CREATE INDEX idx_books_tags_gin ON books USING GIN (tags);
    

  6. Use the GIN index to perform a search query to find books that contain a specific tag in the tags column. Search for books containing the tag "fiction":

    1
    2
    3
    4
    5
    6
    SELECT * FROM books WHERE tags @> ARRAY['fiction'];
     id | title  |        tags
    ----+--------+---------------------
      1 | Book 1 | {fiction,adventure}
      2 | Book 2 | {science,fiction}
    (2 rows)
    

  7. Use the GIN index to search for books that contain both the "fiction" and "adventure" tags.

    1
    2
    3
    4
    5
    SELECT * FROM books WHERE tags @> ARRAY['fiction', 'adventure'];
     id | title  |        tags
    ----+--------+---------------------
      1 | Book 1 | {fiction,adventure}
    (1 row)
    

Using a GIN Index to Search Through the JSONB Type

When using the JSONB type to store and query JSON data, you can use GIN indexes to improve query performance. GIN indexes are suitable for querying JSONB columns that contain a large number of different key-value pairs.

  1. Create the my_table table. The data column stores information about each person using the JSONB type.

    1
    CREATE TABLE my_table (id SERIAL PRIMARY KEY, data JSONB);  
    

  2. Insert data.

    1
    2
    3
    4
    INSERT INTO my_table (data)
     VALUES ('{"name": "John", "age": 30, "address": {"career": "announcer", "state": "NY"}}'),
          ('{"name": "Alice", "age": 25, "address": {"career": "architect", "state": "CA"}}'),
          ('{"name": "Bob", "age": 35, "address": {"career": "dentist", "state": "WA"}}');
    

  3. Create a GIN index to accelerate the query of JSONB columns.

    1
    CREATE INDEX my_table_data_gin_index ON my_table USING GIN (data);
    

  4. Use the GIN index to perform queries on JSONB columns. For example, search for a person whose occupation is dentist::

    1
    2
    3
    4
    5
    SELECT * FROM my_table WHERE data @> '{"address": {"career": "dentist"}}';
     id |                                    data
    ----+-----------------------------------------------------------------------------
      3 | {"age": 35, "name": "Bob", "address": {"state": "WA", "career": "dentist"}}
    (1 row)
    

  5. GIN indexes can also be queried on keys of JSONB columns. For example, search for people who are 30 years old or older:

    1
    2
    3
    4
    5
    6
    SELECT * FROM my_table WHERE data ->> 'age' >= '30';
     id |                                      data
    ----+--------------------------------------------------------------------------------
      3 | {"age": 35, "name": "Bob", "address": {"state": "WA", "career": "dentist"}}
      1 | {"age": 30, "name": "John", "address": {"state": "NY", "career": "announcer"}}
    (2 rows)
    

Using a GIN Index for Full-Text Search

When using GIN indexes for full-text search, you can use the tsvector and tsquery data types and related functions.

NOTE:

To build a tsquery object, you need to use the to_tsquery function and provide the search criteria and the corresponding text search configuration (english in this case). Other text search functions and operators can also be used for more complex full-text searches, such as plainto_tsquery and ts_rank. The specific usage depends on your needs.

  1. Create an articles table in which the content column stores the article content.

    1
    CREATE TABLE articles (id SERIAL PRIMARY KEY,title VARCHAR(100),content TEXT);
    

  2. Insert data.

    1
    2
    3
    4
    5
    INSERT INTO articles (title, content) 
     VALUES ('Article 1', 'This is the content of article 1.'),
       ('Article 2', 'Here is the content for article 2.'),
       ('Article 3', 'This article discusses various topics.'),
       ('Article 4', 'The content of the fourth article is different.');
    

  3. Creates an auxiliary column tsvector for the content column that stores the processed text indexes.

    1
    ALTER TABLE articles ADD COLUMN content_vector tsvector;
    

  4. Update the value in the content_vector column and convert the text in the content column to the tsvector type.

    1
    UPDATE articles SET content_vector = to_tsvector('english', content);
    

  5. Create a GIN index.

    1
    CREATE INDEX idx_articles_content_gin ON articles USING GIN (content_vector);
    

  6. Perform a full-text search, using the tsquery type to specify the search criteria. For example, search for an article that contains the word "content":

    1
    SELECT * FROM articles WHERE content_vector @@ to_tsquery('english', 'content');
    

Sitemizi ve deneyiminizi iyileştirmek için çerezleri kullanırız. Sitemizde tarama yapmaya devam ederek çerez politikamızı kabul etmiş olursunuz. Daha fazla bilgi edinin

Feedback

Feedback

Feedback

0/500

Selected Content

Submit selected content with the feedback