diff --git a/CN/modules/ROOT/images/p31.png b/CN/modules/ROOT/images/p31.png new file mode 100644 index 00000000..51e0e02a Binary files /dev/null and b/CN/modules/ROOT/images/p31.png differ diff --git a/CN/modules/ROOT/images/p32.png b/CN/modules/ROOT/images/p32.png new file mode 100644 index 00000000..d8cc211d Binary files /dev/null and b/CN/modules/ROOT/images/p32.png differ diff --git a/CN/modules/ROOT/nav.adoc b/CN/modules/ROOT/nav.adoc index dfa55342..fb98c260 100644 --- a/CN/modules/ROOT/nav.adoc +++ b/CN/modules/ROOT/nav.adoc @@ -13,8 +13,12 @@ *** xref:master/4.4.adoc[运维管理指南] *** xref:master/4.5.adoc[迁移指南] ** IvorySQL生态 -*** xref:master/5.1.adoc[PostGIS] +*** xref:master/5.0.adoc[概述] *** xref:master/5.2.adoc[pgvector] +*** xref:master/5.3.adoc[pgddl(DDL Extractor)] +*** xref:master/5.4.adoc[pg_cron] +*** xref:master/5.5.adoc[pgsql-http] +*** xref:master/5.6.adoc[plpgsql_check] ** IvorySQL架构设计 *** 查询处理 **** xref:master/6.1.1.adoc[双parser] diff --git a/CN/modules/ROOT/pages/master/5.0.adoc b/CN/modules/ROOT/pages/master/5.0.adoc new file mode 100644 index 00000000..6ea7aa1d --- /dev/null +++ b/CN/modules/ROOT/pages/master/5.0.adoc @@ -0,0 +1,24 @@ +:sectnums: +:sectnumlevels: 5 + + +[discrete] +== IvorySQL生态插件适配列表 + +IvorySQL 作为一款兼容 Oracle 且基于 PostgreSQL 的高级开源数据库,具备强大的扩展能力,支持丰富的生态系统插件。这些插件可以帮助用户在不同场景下增强数据库功能,包括地理信息处理、向量检索、全文搜索、数据定义提取和路径规划等。以下是当前 IvorySQL 官方兼容和支持的主要插件列表: + ++ + +[cols="2,1,3,3"] +|==== +|*插件名称*|*版本*|*功能描述*|*适用场景* +| xref:master/5.2.adoc[pgvector] | 0.8.1 | 支持向量相似性搜索,可用于存储和检索高维向量数据| AI 应用、图像检索、推荐系统、语义搜索 +| xref:master/5.3.adoc[pgddl (DDL Extractor)] | 0.31 | 提取数据库中的 DDL(数据定义语言)语句,便于版本管理和迁移 | 数据库版本控制、CI/CD 集成、结构比对与同步 +| xref:master/5.4.adoc[pg_cron]​ | 1.6.0 | 提供数据库内部的定时任务调度功能,支持定期执行SQL语句 | 数据清理、定期统计、自动化维护任务 +| xref:master/5.5.adoc[pgsql-http]​ | 1.7.0 | 允许在SQL中发起HTTP请求,与外部Web服务进行交互 | 数据采集、API集成、微服务调用 +| xref:master/5.6.adoc[plpgsql_check] | 2.8 | 提供PL/pgSQL代码的静态分析功能,可在开发阶段发现潜在错误 | 存储过程开发、代码质量检查、调试优化 +|==== + +这些插件均经过 IvorySQL 团队的测试和适配,确保在 IvorySQL 环境下稳定运行。用户可以根据业务需求选择合适的插件,进一步提升数据库系统的能力和灵活性。 + +我们也将持续扩展和丰富 IvorySQL 的插件生态,欢迎社区开发者提交新的插件适配建议或代码贡献。如需了解更多每个插件的详细使用方法和最新兼容版本,请参阅各插件对应的文档章节。 \ No newline at end of file diff --git a/CN/modules/ROOT/pages/master/5.2.adoc b/CN/modules/ROOT/pages/master/5.2.adoc index cdde9528..fa7e298d 100644 --- a/CN/modules/ROOT/pages/master/5.2.adoc +++ b/CN/modules/ROOT/pages/master/5.2.adoc @@ -23,38 +23,46 @@ HNSW (Hierarchical Navigating Small World) 是一种基于图的索引算法, == 安装 [TIP] ==== -环境中已经安装了IvorySQL4.5及以上版本,安装路径为/usr/local/ivorysql/ivorysql-4 +环境中已经安装了IvorySQL5及以上版本,安装路径为/usr/local/ivorysql/ivorysql-5 ==== === 源码安装 ** 设置PG_CONFIG环境变量 -``` -export PG_CONFIG=/usr/local/ivorysql/ivorysql-4/bin/pg_config -``` ++ +[literal] +---- +export PG_CONFIG=/usr/local/ivorysql/ivorysql-5/bin/pg_config +---- ** 拉取pg_vector源码 -``` ++ +[literal] +---- git clone --branch v0.8.1 https://github.com/pgvector/pgvector.git -``` +---- ** 安装 pgvector -``` ++ +[literal] +---- cd pgvector sudo --preserve-env=PG_CONFIG make sudo --preserve-env=PG_CONFIG make install -``` +---- ** 创建pgvector扩展 -``` -[ivorysql@localhost ivorysql-4]$ psql -psql (17.5) ++ +[literal] +---- +[ivorysql@localhost ivorysql-5]$ psql +psql (18.0) Type "help" for help. ivorysql=# create extension vector; CREATE EXTENSION -``` +---- 至此,pgvector扩展安装已完成。 更多用例,请参考 https://github.com/pgvector/pgvector?tab=readme-ov-file#getting-started[pgvector文档] @@ -66,7 +74,8 @@ CREATE EXTENSION === 数据类型 -``` +[literal] +---- ivorysql=# CREATE TABLE items5 (id bigserial PRIMARY KEY, name varchar2(20), num number(20), embedding bit(3)); CREATE TABLE ivorysql=# INSERT INTO items5 (name, num, embedding) VALUES ('1st oracle data',0, '000'), ('2nd oracle data', 111, '111'); @@ -76,11 +85,12 @@ ivorysql=# SELECT * FROM items5 ORDER BY bit_count(embedding # '101') LIMIT 5; ----+-----------------+-----+----------- 2 | 2nd oracle data | 111 | 111 1 | 1st oracle data | 0 | 000 -``` +---- === 匿名块 -``` +[literal] +---- ivorysql=# declare i vector(3) := '[1,2,3]'; begin @@ -89,10 +99,11 @@ end; ivorysql-# / NOTICE: [1,2,3] DO -``` +---- === 存储过程(PROCEDURE) -``` +[literal] +---- ivorysql=# CREATE OR REPLACE PROCEDURE ora_procedure() AS p vector(3) := '[4,5,6]'; @@ -104,10 +115,11 @@ CREATE PROCEDURE ivorysql=# call ora_procedure(); NOTICE: [4,5,6] CALL -``` +---- ==== 函数(FUNCTION) -``` +[literal] +---- ivorysql=# CREATE OR REPLACE FUNCTION AddVector(a vector(3), b vector(3)) RETURN vector(3) IS @@ -121,4 +133,4 @@ ivorysql=# SELECT AddVector('[1,2,3]','[4,5,6]') FROM DUAL; ---------------- [5,7,9] (1 row) -``` \ No newline at end of file +---- diff --git a/CN/modules/ROOT/pages/master/5.3.adoc b/CN/modules/ROOT/pages/master/5.3.adoc new file mode 100644 index 00000000..3f678833 --- /dev/null +++ b/CN/modules/ROOT/pages/master/5.3.adoc @@ -0,0 +1,47 @@ + +:sectnums: +:sectnumlevels: 5 + += pgddl (DDL Extractor) + +== 概述 +pgddl 是一个专为 PostgreSQL 数据库设计的 SQL 函数扩展,它能够直接从数据库系统目录中生成清晰、格式化的 SQL DDL (数据定义语言) 脚本,例如 CREATE TABLE 或 ALTER FUNCTION。它解决了 PostgreSQL 原生缺乏类似 SHOW CREATE TABLE 命令的问题,让用户无需借助外部工具(如 pg_dump)即可在纯 SQL 环境中轻松获取对象的创建语句。 + +该扩展通过一组简单的 SQL 函数提供了一套完整的解决方案,其优势包括:仅需使用 SQL 查询即可操作、支持通过 WHERE 子句灵活筛选对象、并能智能处理对象之间的依赖关系,生成包含 Drop 和 Create 步骤的完整脚本。这使得它特别适用于数据库变更管理、升级脚本编写和结构审计等场景。 + +需要注意的是,ddlx 仍在发展中,可能尚未覆盖所有 PostgreSQL 对象类型和高级选项。生成的脚本建议始终在非生产环境中先行检查和测试,以确保其正确性与安全性。 + +== 安装 +IvorySQL的安装包里已经集成了pgddl插件,如果使用安装包安装的IvorySQL,通常不需要再手动安装pgddl即可使用。其它安装方式可以参考下面的源码安装步骤。 + +[TIP] +源码安装环境为 Ubuntu 24.04(x86_64),环境中已经安装了IvorySQL5及以上版本,安装路径为/usr/local/ivorysql/ivorysql-5 + +=== 源码安装 +从https://github.com/lacanoid/pgddl 下载pgddl v0.31代码。 + +[literal] +---- +cd pgddl +# 设置PG_CONFIG环境变量值为pg_config路径,eg:/usr/local/ivorysql/ivorysql-5/bin/pg_config +make PG_CONFIG=/path/to/pg_config +make PG_CONFIG=/path/to/pg_config install +---- + +== 创建Extension并确认ddlx版本 + +psql 连接到数据库,执行如下命令: +[literal] +---- +ivorysql=# CREATE extension ddlx; +CREATE EXTENSION + +ivorysql=# SELECT * FROM pg_available_extensions WHERE name = 'ddlx'; + name | default_version | installed_version | comment +------+-----------------+-------------------+------------------------- + ddlx | 0.31 | 0.31 | DDL eXtractor functions +(1 row) +---- + +== 使用 +关于pgddl的使用,请参阅 https://github.com/lacanoid/pgddl[ddlx官方文档] \ No newline at end of file diff --git a/CN/modules/ROOT/pages/master/5.4.adoc b/CN/modules/ROOT/pages/master/5.4.adoc new file mode 100644 index 00000000..b34ee9e2 --- /dev/null +++ b/CN/modules/ROOT/pages/master/5.4.adoc @@ -0,0 +1,118 @@ + +:sectnums: +:sectnumlevels: 5 +:imagesdir: ./_images + += pg_cron + +== 概述 +在 PostgreSQL 中运行周期性任务,例如执行 VACUUM或删除旧数据,是一种常见需求。实现这一点的简单方法是配置 cron或其他外部守护进程,使其定期连接到数据库并运行命令。然而,随着数据库越来越多地作为托管服务或独立容器运行,配置和运行一个单独的守护进程通常变得不切实际。此外,很难让您的 cron任务感知故障转移,或者跨集群节点调度任务。 + +pg_cron 是 PostgreSQL 的开源定时任务扩展,允许直接在数据库内部设置 cron 风格的任务调度,用于自动化数据维护任务(清理,聚合), 数据库健康检查,执行存储过程和自定义函数等操作。它将cron任务存储在表中,周期性任务会随着 PostgreSQL 服务器自动进行故障转移。详情可以参见 https://github.com/citusdata/pg_cron[pg_cron文档]。 + +== 安装配置 + +[TIP] +源码安装环境为 Ubuntu 24.04(x86_64),环境中已经安装了IvorySQL5及以上版本,安装路径为/usr/local/ivorysql/ivorysql-5 + +=== 源码安装 + +[literal] +---- +# 拉取pg_cron源码 +git clone https://github.com/citusdata/pg_cron.git +cd pg_cron +# 将pg_config的路径设置到PATH环境变量里,eg: +export PATH=/usr/local/ivorysql/ivorysql-5/bin/:$PATH +make +make install +---- + +=== 配置文件 (ivorysql.conf) + +[literal] +---- +# 共享预加载扩展 +shared_preload_libraries = 'pg_cron' + +# 指定任务元数据存储库(默认当前库) +cron.database_name = 'ivorysql' + +# 允许的最大并发任务数 +cron.max_running_jobs = 5 +---- + +=== 重启服务 + +[literal] +---- +pg_ctl restart -D ./data -l logfile +---- + +=== 创建Extension并确认pg_cron版本 + +psql 连接到数据库,执行如下命令: +[literal] +---- +ivorysql=# CREATE extension pg_cron; +CREATE EXTENSION + +ivorysql=# SELECT * FROM pg_available_extensions WHERE name = 'pg_cron'; + name | default_version | installed_version | comment +---------+-----------------+-------------------+--------------------------- + pg_cron | 1.6 | |Job scheduler for PostgreSQL +(1 row) +---- + +== 核心功能使用 + +=== 创建定时任务 + +[literal] +---- +SELECT cron.schedule( + 'nightly-data-cleanup', -- 任务名称(唯一标识) + '0 3 * * *', -- cron表达式(每天UTC 3:00) + $$DELETE FROM logs + WHERE created_at < now() - interval '30 days'$$ -- 执行SQL +); +---- + +cron表达式速查表: + +|==== +|示例|含义 +|'0 * * * *'|每小时整点执行 +|'*/15 * * * *'|每15分钟执行 +|'0 9 * * 1-5'|工作日早9点执行 +|'0 1 1 * *'|每月1日凌晨1点执行 +|==== + +pg_cron还允许使用 '$'表示月份的最后一天。 + +=== 任务管理 + +[literal] +---- +# 查看所有任务 +SELECT * FROM cron.job; +---- + +image::p31.png[] + +[literal] +---- +# 查看任务执行历史 +SELECT * FROM cron.job_run_details ORDER BY start_time DESC LIMIT 10; +---- + +image::p32.png[] + +[literal] +---- +# 删除任务 +SELECT cron.unschedule('nightly-data-cleanup'); + +# 暂停任务(更新状态) +UPDATE cron.job SET active = false WHERE jobname = 'delete-job-run-details'; +---- diff --git a/CN/modules/ROOT/pages/master/5.5.adoc b/CN/modules/ROOT/pages/master/5.5.adoc new file mode 100644 index 00000000..e67414fa --- /dev/null +++ b/CN/modules/ROOT/pages/master/5.5.adoc @@ -0,0 +1,59 @@ + +:sectnums: +:sectnumlevels: 5 + += pgsql-http + +== 概述 +pgsql-http 是一个为 PostgreSQL 数据库设计的开源扩展,它允许用户直接在数据库内部发起 HTTP 请求,扮演了一个内置 Web 客户端的角色。该扩展的核心目的是打通数据库与外部 Web 服务之间的壁垒,使得通过简单的 SQL 函数调用即可与外部 Web 服务、API 端点进行交互,无需依赖外部应用程序或中间件。 + +借助此扩展,开发者可以在 SQL 查询、触发器或存储过程中直接获取网络数据(GET)、提交数据(POST/PUT)、更新(PATCH)或删除(DELETE)远程资源。它提供了丰富的功能,包括设置请求头、自动处理 URL 编码、发送 JSON 数据以及解析响应状态、头部和内容,极大简化了将外部数据集成到数据库操作中的流程。 + +其典型应用场景包括:实时获取外部数据(如汇率、天气信息)并存入表;在数据变更时通过触发器自动通知微服务;对数据库中的数据进行清洗后直接提交至外部 API 等。它为构建以数据库为中心的集成应用提供了强大而灵活的解决方案。 + +== 安装 +IvorySQL的安装包里已经集成了pgsql-http插件,如果使用安装包安装的IvorySQL,通常不需要再手动安装pgsql-http即可使用。其它安装方式可以参考下面的源码安装步骤。 + +[TIP] +源码安装环境为 Ubuntu 24.04(x86_64),环境中已经安装了IvorySQL5及以上版本,安装路径为/usr/local/ivorysql/ivorysql-5 + +=== 源码安装 + +** 安装依赖 + +对libcurl有依赖,libcurl的开发文件(例如 libcurl4-openssl-dev)需要提前安装上 +[literal] +---- +#安装依赖 +sudo apt install libcurl4-openssl-dev +---- + +** 编译安装 + +从https://github.com/pramsey/pgsql-http/releases/tag/v1.7.0 下载 1.7.0的源码包 pgsql-http-1.7.0.tar.gz +[literal] +---- +tar xvf pgsql-http-1.7.0.tar.gz +cd pgsql-http-1.7.0 +# 确保pg_config在PATH里可以访问,eg: /usr/local/ivorysql/ivorysql-5/bin/pg_config +make +sudo make install +---- + +== 创建Extension并确认http版本 + +psql 连接到数据库,执行如下命令: +[literal] +---- +ivorysql=# CREATE extension http; +CREATE EXTENSION + +ivorysql=# SELECT * FROM pg_available_extensions WHERE name = 'http'; + name | default_version | installed_version | comment +-----------+-----------------+-------------------+------------------------------------------------------------------------- + http | 1.7 | 1.7 | HTTP client for PostgreSQL, allows web page retrieval inside the database. +(1 row) +---- + +== 使用 +关于pgsql-http的使用,请参阅 https://github.com/pramsey/pgsql-http[pgsql-http官方文档] \ No newline at end of file diff --git a/CN/modules/ROOT/pages/master/5.6.adoc b/CN/modules/ROOT/pages/master/5.6.adoc new file mode 100644 index 00000000..8f751e05 --- /dev/null +++ b/CN/modules/ROOT/pages/master/5.6.adoc @@ -0,0 +1,79 @@ + +:sectnums: +:sectnumlevels: 5 + += plpgsql_check + +== 概述 +在 PostgreSQL 数据库开发过程中,编写存储过程和函数时往往难以在运行前发现代码中的语法错误、类型不匹配、未定义变量等潜在问题。传统方式需要等到函数实际执行时才能发现这些错误,这不仅增加了调试成本,也可能在生产环境中引发意外故障。 + +plpgsql_check 是一个专为 PostgreSQL 的 PL/pgSQL 语言设计的静态代码分析工具(Linter),它能够在不实际执行函数的情况下,对存储过程和函数的源代码进行深度检查。该工具可以提前发现语法错误、类型不匹配、未使用的变量、性能问题、安全隐患等多种代码质量问题,帮助开发者在开发阶段就确保代码的正确性和健壮性。详情可以参见 https://github.com/okbob/plpgsql_check[plpgsql_check官方文档]。 + +== 安装 + +[TIP] +源码安装环境为 Ubuntu 24.04(x86_64),环境中已经安装了IvorySQL5及以上版本,安装路径为/usr/local/ivorysql/ivorysql-5 + +=== 源码安装 + +[literal] +---- +# 从https://github.com/okbob/plpgsql_check/releases/tag/v2.8.3 下载 2.8.3的源码包 plpgsql_check-2.8.3.tar.gz +tar xvf plpgsql_check-2.8.3.tar.gz +cd plpgsql_check-2.8.3 +# 将pg_config的路径设置到PATH环境变量里,eg: +export PATH=/usr/local/ivorysql/ivorysql-5/bin/:$PATH +make USE_PGXS=1 clean +make USE_PGXS=1 all +sudo make USE_PGXS=1 install +---- + +== 创建Extension并确认plpgsql_check版本 + +psql 连接到数据库,执行如下命令: +[literal] +---- +ivorysql=# CREATE EXTENSION plpgsql_check; +CREATE EXTENSION + +ivorysql=# SELECT * FROM pg_available_extensions WHERE name = 'plpgsql_check'; + name | default_version | installed_version | comment +---------------+-----------------+-------------------+--------------------------------------------------- + plpgsql_check | 2.8 | 2.8 | extended check for plpgsql functions +(1 row) +---- + +== 使用 + +=== 检查单个函数 + +[literal] +---- +-- 创建一个示例函数 +CREATE OR REPLACE FUNCTION test_function(p_id integer) +RETURNS text AS $$ +DECLARE + v_name text; + v_unused integer; -- 未使用的变量 +BEGIN + SELECT name INTO v_name FROM users WHERE id = p_id; + RETURN v_naem; -- 拼写错误 +END; +$$ LANGUAGE plpgsql; + +-- 使用 plpgsql_check 检查函数 +SELECT * FROM plpgsql_check_function('test_function(integer)'); +---- + +检查结果示例: +[literal] +---- + plpgsql_check_function +-------------------------------------------------------------- + error:42601:7:assignment:target variable "v_naem" is undefined + warning:00000:4:DECLARE:unused variable "v_unused" +(2 rows) +---- + +更多详细使用方法和高级特性,请参阅 https://github.com/okbob/plpgsql_check[plpgsql_check官方文档]。 + diff --git a/EN/modules/ROOT/images/p31.png b/EN/modules/ROOT/images/p31.png new file mode 100644 index 00000000..51e0e02a Binary files /dev/null and b/EN/modules/ROOT/images/p31.png differ diff --git a/EN/modules/ROOT/images/p32.png b/EN/modules/ROOT/images/p32.png new file mode 100644 index 00000000..d8cc211d Binary files /dev/null and b/EN/modules/ROOT/images/p32.png differ diff --git a/EN/modules/ROOT/nav.adoc b/EN/modules/ROOT/nav.adoc index 7250cf26..9498183e 100644 --- a/EN/modules/ROOT/nav.adoc +++ b/EN/modules/ROOT/nav.adoc @@ -12,8 +12,12 @@ ** xref:master/4.4.adoc[Operation Management] ** xref:master/4.5.adoc[Migration] * IvorySQL Ecosystem -** xref:master/5.1.adoc[PostGIS] +** xref:master/5.0.adoc[Overview] ** xref:master/5.2.adoc[pgvector] +** xref:master/5.3.adoc[pgddl(DDL Extractor)] +** xref:master/5.4.adoc[pg_cron] +** xref:master/5.5.adoc[pgsql-http] +** xref:master/5.6.adoc[plpgsql_check] * IvorySQL Architecture Design ** Query Processing *** xref:master/6.1.1.adoc[Dual Parser] diff --git a/EN/modules/ROOT/pages/master/5.0.adoc b/EN/modules/ROOT/pages/master/5.0.adoc new file mode 100644 index 00000000..437b44cd --- /dev/null +++ b/EN/modules/ROOT/pages/master/5.0.adoc @@ -0,0 +1,24 @@ +:sectnums: +:sectnumlevels: 5 + + +[discrete] +== IvorySQL Ecosystem Plugin Compatibility List + +IvorySQL, as an advanced open-source database compatible with Oracle and based on PostgreSQL, has powerful extension capabilities and supports a rich ecosystem of plugins. These plugins can help users enhance database functionality in different scenarios, including geospatial information processing, vector retrieval, full-text search, data definition extraction, and path planning. The following is a list of major plugins currently officially compatible with and supported by IvorySQL: + ++ + +[cols="2,1,3,3"] +|==== +|*Plugin Name*|*Version*|*Function Description*|*Use Cases* +| xref:master/5.2.adoc[pgvector] | 0.8.1 | Supports vector similarity search, can be used to store and retrieve high-dimensional vector data| AI applications, image retrieval, recommendation systems, semantic search +| xref:master/5.3.adoc[pgddl (DDL Extractor)] | 0.31 | Extracts DDL (Data Definition Language) statements from databases, facilitating version management and migration | Database version control, CI/CD integration, structure comparison and synchronization +| xref:master/5.4.adoc[pg_cron]​ | 1.6.0 | Provides database-internal scheduled task scheduling functionality, supports regular SQL statement execution | Data cleanup, regular statistics, automated maintenance tasks +| xref:master/5.5.adoc[pgsql-http]​ | 1.7.0 | Allows HTTP requests to be initiated in SQL, interacting with external web services | Data collection, API integration, microservice calls +| xref:master/5.6.adoc[plpgsql_check] | 2.8 | Provides static analysis functionality for PL/pgSQL code, can detect potential errors during development | Stored procedure development, code quality checking, debugging and optimization +|==== + +These plugins have all been tested and adapted by the IvorySQL team to ensure stable operation in the IvorySQL environment. Users can select appropriate plugins based on business needs to further enhance the capabilities and flexibility of the database system. + +We will continue to expand and enrich the IvorySQL plugin ecosystem. Community developers are welcome to submit new plugin adaptation suggestions or code contributions. For more detailed usage methods and the latest compatible versions of each plugin, please refer to the corresponding documentation chapters for each plugin. diff --git a/EN/modules/ROOT/pages/master/5.2.adoc b/EN/modules/ROOT/pages/master/5.2.adoc index dd965a4d..3d9a162b 100644 --- a/EN/modules/ROOT/pages/master/5.2.adoc +++ b/EN/modules/ROOT/pages/master/5.2.adoc @@ -26,38 +26,46 @@ HNSW (Hierarchical Navigating Small World) is a graph-based indexing algorithm c == Installation [TIP] ==== -The IvorySQL 4.5(above version) has been installed in the environment, and the installation path is /usr/local/ivorysql/ivorysql-4 +The IvorySQL 5(above version) has been installed in the environment, and the installation path is /usr/local/ivorysql/ivorysql-5 ==== === Source Code Installation ** Setting PG_CONFIG -``` -export PG_CONFIG=/usr/local/ivorysql/ivorysql-4/bin/pg_config -``` ++ +[literal] +---- +export PG_CONFIG=/usr/local/ivorysql/ivorysql-5/bin/pg_config +---- ** Pull pg_vector source code -``` -git clone --branch v0.6.2 https://github.com/pgvector/pgvector.git -``` ++ +[literal] +---- +git clone --branch v0.8.1 https://github.com/pgvector/pgvector.git +---- ** Install pgvector -``` ++ +[literal] +---- cd pgvector sudo --preserve-env=PG_CONFIG make sudo --preserve-env=PG_CONFIG make install -``` +---- ** Create pgvector extension -``` ++ +[literal] +---- [ivorysql@localhost ivorysql-4]$ psql -psql (17.5) +psql (18.0) Type "help" for help. ivorysql=# create extension vector; CREATE EXTENSION -``` +---- Now, pgvector is installed completely. For more usage cases, please refer to https://github.com/pgvector/pgvector?tab=readme-ov-file#getting-started[pgvector document] @@ -68,7 +76,8 @@ We suggest users to test using port 1521, using the command: psql -p 1521. === Data Type -``` +[literal] +---- ivorysql=# CREATE TABLE items5 (id bigserial PRIMARY KEY, name varchar2(20), num number(20), embedding bit(3)); CREATE TABLE ivorysql=# INSERT INTO items5 (name, num, embedding) VALUES ('1st oracle data',0, '000'), ('2nd oracle data', 111, '111'); @@ -78,11 +87,12 @@ ivorysql=# SELECT * FROM items5 ORDER BY bit_count(embedding # '101') LIMIT 5; ----+-----------------+-----+----------- 2 | 2nd oracle data | 111 | 111 1 | 1st oracle data | 0 | 000 -``` +---- === Anonymous Block -``` +[literal] +---- ivorysql=# declare i vector(3) := '[1,2,3]'; begin @@ -91,10 +101,11 @@ end; ivorysql-# / NOTICE: [1,2,3] DO -``` +---- === PROCEDURE -``` +[literal] +---- ivorysql=# CREATE OR REPLACE PROCEDURE ora_procedure() AS p vector(3) := '[4,5,6]'; @@ -106,10 +117,11 @@ CREATE PROCEDURE ivorysql=# call ora_procedure(); NOTICE: [4,5,6] CALL -``` +---- ==== FUNCTION -``` +[literal] +---- ivorysql=# CREATE OR REPLACE FUNCTION AddVector(a vector(3), b vector(3)) RETURN vector(3) IS @@ -123,4 +135,4 @@ ivorysql=# SELECT AddVector('[1,2,3]','[4,5,6]') FROM DUAL; ---------------- [5,7,9] (1 row) -``` \ No newline at end of file +---- diff --git a/EN/modules/ROOT/pages/master/5.3.adoc b/EN/modules/ROOT/pages/master/5.3.adoc new file mode 100644 index 00000000..2fa56fe1 --- /dev/null +++ b/EN/modules/ROOT/pages/master/5.3.adoc @@ -0,0 +1,46 @@ +:sectnums: +:sectnumlevels: 5 + += pgddl (DDL Extractor) + +== Overview +pgddl is a SQL function extension specifically designed for PostgreSQL databases. It can generate clear, formatted SQL DDL (Data Definition Language) scripts directly from the database system catalog, such as CREATE TABLE or ALTER FUNCTION. It solves the problem that PostgreSQL natively lacks commands like SHOW CREATE TABLE, allowing users to easily obtain object creation statements in a pure SQL environment without relying on external tools (such as pg_dump). + +This extension provides a complete solution through a set of simple SQL functions, with advantages including: requiring only SQL queries to operate, supporting flexible object filtering through WHERE clauses, and intelligently handling dependencies between objects to generate complete scripts including Drop and Create steps. This makes it particularly suitable for scenarios such as database change management, upgrade script writing, and structural auditing. + +It should be noted that ddlx is still under development and may not yet cover all PostgreSQL object types and advanced options. Generated scripts should always be checked and tested in non-production environments first to ensure their correctness and safety. + +== Installation +The IvorySQL installation package already integrates the pgddl plugin. If IvorySQL is installed using the installation package, pgddl can usually be used without manual installation. Other installation methods can refer to the source code installation steps below. + +[TIP] +The source installation environment is Ubuntu 24.04 (x86_64). IvorySQL 5 or higher version is already installed in the environment, with the installation path at /usr/local/ivorysql/ivorysql-5 + +=== Source Installation +Download pgddl v0.31 code from https://github.com/lacanoid/pgddl. + +[literal] +---- +cd pgddl +# Set the PG_CONFIG environment variable to the pg_config path, e.g.: /usr/local/ivorysql/ivorysql-5/bin/pg_config +make PG_CONFIG=/path/to/pg_config +make PG_CONFIG=/path/to/pg_config install +---- + +== Create Extension and Confirm ddlx Version + +Connect to the database with psql and execute the following commands: +[literal] +---- +ivorysql=# CREATE extension ddlx; +CREATE EXTENSION + +ivorysql=# SELECT * FROM pg_available_extensions WHERE name = 'ddlx'; + name | default_version | installed_version | comment +------+-----------------+-------------------+------------------------- + ddlx | 0.31 | 0.31 | DDL eXtractor functions +(1 row) +---- + +== Usage +For pgddl usage, please refer to the https://github.com/lacanoid/pgddl[ddlx Official Documentation] diff --git a/EN/modules/ROOT/pages/master/5.4.adoc b/EN/modules/ROOT/pages/master/5.4.adoc new file mode 100644 index 00000000..b096ecc5 --- /dev/null +++ b/EN/modules/ROOT/pages/master/5.4.adoc @@ -0,0 +1,117 @@ +:sectnums: +:sectnumlevels: 5 +:imagesdir: ./_images + += pg_cron + +== Overview +Running periodic tasks in PostgreSQL, such as executing VACUUM or deleting old data, is a common requirement. A simple way to achieve this is to configure cron or other external daemons to periodically connect to the database and run commands. However, as databases increasingly run as managed services or standalone containers, configuring and running a separate daemon often becomes impractical. Additionally, it's difficult to make your cron jobs aware of failover or schedule tasks across cluster nodes. + +pg_cron is an open-source scheduled task extension for PostgreSQL that allows setting up cron-style task scheduling directly within the database for automating data maintenance tasks (cleanup, aggregation), database health checks, executing stored procedures and custom functions, and other operations. It stores cron jobs in tables, and periodic tasks automatically fail over with the PostgreSQL server. For more details, see https://github.com/citusdata/pg_cron[pg_cron documentation]. + +== Installation and Configuration + +[TIP] +The source installation environment is Ubuntu 24.04 (x86_64). IvorySQL 5 or higher version is already installed in the environment, with the installation path at /usr/local/ivorysql/ivorysql-5 + +=== Source Installation + +[literal] +---- +# Clone pg_cron source code +git clone https://github.com/citusdata/pg_cron.git +cd pg_cron +# Set pg_config path to PATH environment variable, e.g.: +export PATH=/usr/local/ivorysql/ivorysql-5/bin/:$PATH +make +make install +---- + +=== Configuration File (ivorysql.conf) + +[literal] +---- +# Shared preload extensions +shared_preload_libraries = 'pg_cron' + +# Specify task metadata storage database (default current database) +cron.database_name = 'ivorysql' + +# Maximum number of concurrent tasks allowed +cron.max_running_jobs = 5 +---- + +=== Restart Service + +[literal] +---- +pg_ctl restart -D ./data -l logfile +---- + +=== Create Extension and Confirm pg_cron Version + +Connect to the database with psql and execute the following commands: +[literal] +---- +ivorysql=# CREATE extension pg_cron; +CREATE EXTENSION + +ivorysql=# SELECT * FROM pg_available_extensions WHERE name = 'pg_cron'; + name | default_version | installed_version | comment +---------+-----------------+-------------------+--------------------------- + pg_cron | 1.6 | |Job scheduler for PostgreSQL +(1 row) +---- + +== Core Functionality Usage + +=== Creating Scheduled Tasks + +[literal] +---- +SELECT cron.schedule( + 'nightly-data-cleanup', -- Task name (unique identifier) + '0 3 * * *', -- Cron expression (daily at UTC 3:00) + $$DELETE FROM logs + WHERE created_at < now() - interval '30 days'$$ -- SQL to execute +); +---- + +Cron expression quick reference: + +|==== +|Example|Meaning +|'0 * * * *'|Execute every hour on the hour +|'*/15 * * * *'|Execute every 15 minutes +|'0 9 * * 1-5'|Execute at 9 AM on weekdays +|'0 1 1 * *'|Execute at 1 AM on the 1st of every month +|==== + +pg_cron also allows using '$' to represent the last day of the month. + +=== Task Management + +[literal] +---- +# View all tasks +SELECT * FROM cron.job; +---- + +image::p31.png[] + +[literal] +---- +# View task execution history +SELECT * FROM cron.job_run_details ORDER BY start_time DESC LIMIT 10; +---- + +image::p32.png[] + +[literal] +---- +# Delete task +SELECT cron.unschedule('nightly-data-cleanup'); + +# Pause task (update status) +UPDATE cron.job SET active = false WHERE jobname = 'delete-job-run-details'; +---- diff --git a/EN/modules/ROOT/pages/master/5.5.adoc b/EN/modules/ROOT/pages/master/5.5.adoc new file mode 100644 index 00000000..ba44b0c0 --- /dev/null +++ b/EN/modules/ROOT/pages/master/5.5.adoc @@ -0,0 +1,58 @@ +:sectnums: +:sectnumlevels: 5 + += pgsql-http + +== Overview +pgsql-http is an open-source extension designed for PostgreSQL databases that allows users to initiate HTTP requests directly within the database, acting as a built-in web client. The core purpose of this extension is to bridge the gap between databases and external web services, enabling interaction with external web services and API endpoints through simple SQL function calls without relying on external applications or middleware. + +With this extension, developers can directly retrieve network data (GET), submit data (POST/PUT), update (PATCH), or delete (DELETE) remote resources in SQL queries, triggers, or stored procedures. It provides rich functionality, including setting request headers, automatic URL encoding, sending JSON data, and parsing response status, headers, and content, greatly simplifying the process of integrating external data into database operations. + +Typical application scenarios include: real-time retrieval of external data (such as exchange rates, weather information) and storing it in tables; automatic notification of microservices through triggers when data changes; cleaning data in the database and directly submitting it to external APIs. It provides a powerful and flexible solution for building database-centric integrated applications. + +== Installation +The pgsql-http plugin has been integrated into the IvorySQL installation package. If IvorySQL is installed using the installation package, pgsql-http can usually be used without manual installation. Other installation methods can refer to the source code installation steps below. + +[TIP] +The source installation environment is Ubuntu 24.04 (x86_64). IvorySQL 5 or higher version is already installed in the environment, with the installation path at /usr/local/ivorysql/ivorysql-5 + +=== Source Installation + +** Install Dependencies + +It depends on libcurl, and libcurl development files (such as libcurl4-openssl-dev) need to be installed in advance +[literal] +---- +# Install dependencies +sudo apt install libcurl4-openssl-dev +---- + +** Compile and Install + +Download the 1.7.0 source package pgsql-http-1.7.0.tar.gz from https://github.com/pramsey/pgsql-http/releases/tag/v1.7.0 +[literal] +---- +tar xvf pgsql-http-1.7.0.tar.gz +cd pgsql-http-1.7.0 +# Ensure pg_config is accessible in PATH, e.g.: /usr/local/ivorysql/ivorysql-5/bin/pg_config +make +sudo make install +---- + +== Create Extension and Confirm http Version + +Connect to the database with psql and execute the following commands: +[literal] +---- +ivorysql=# CREATE extension http; +CREATE EXTENSION + +ivorysql=# SELECT * FROM pg_available_extensions WHERE name = 'http'; + name | default_version | installed_version | comment +-----------+-----------------+-------------------+------------------------------------------------------------------------- + http | 1.7 | 1.7 | HTTP client for PostgreSQL, allows web page retrieval inside the database. +(1 row) +---- + +== Usage +For pgsql-http usage, please refer to https://github.com/pramsey/pgsql-http[pgsql-http official documentation] diff --git a/EN/modules/ROOT/pages/master/5.6.adoc b/EN/modules/ROOT/pages/master/5.6.adoc new file mode 100644 index 00000000..3551bca4 --- /dev/null +++ b/EN/modules/ROOT/pages/master/5.6.adoc @@ -0,0 +1,79 @@ + +:sectnums: +:sectnumlevels: 5 + += plpgsql_check + +== Overview +During PostgreSQL database development, when writing stored procedures and functions, it is often difficult to discover potential issues such as syntax errors, type mismatches, undefined variables, etc., before runtime. Traditional approaches require waiting until the function is actually executed to discover these errors, which not only increases debugging costs but may also cause unexpected failures in production environments. + +plpgsql_check is a static code analysis tool (Linter) specifically designed for PostgreSQL's PL/pgSQL language. It can perform deep checks on the source code of stored procedures and functions without actually executing them. This tool can proactively identify various code quality issues including syntax errors, type mismatches, unused variables, performance problems, security vulnerabilities, etc., helping developers ensure code correctness and robustness during the development phase. For more details, see https://github.com/okbob/plpgsql_check[plpgsql_check official documentation]. + +== Installation + +[TIP] +The source installation environment is Ubuntu 24.04 (x86_64). IvorySQL 5 or higher version is already installed in the environment, with the installation path at /usr/local/ivorysql/ivorysql-5 + +=== Source Installation + +[literal] +---- +# Download the 2.8.3 source package plpgsql_check-2.8.3.tar.gz from https://github.com/okbob/plpgsql_check/releases/tag/v2.8.3 +tar xvf plpgsql_check-2.8.3.tar.gz +cd plpgsql_check-2.8.3 +# Set pg_config path to PATH environment variable, e.g.: +export PATH=/usr/local/ivorysql/ivorysql-5/bin/:$PATH +make USE_PGXS=1 clean +make USE_PGXS=1 all +sudo make USE_PGXS=1 install +---- + +== Create Extension and Confirm plpgsql_check Version + +Connect to the database with psql and execute the following commands: +[literal] +---- +ivorysql=# CREATE EXTENSION plpgsql_check; +CREATE EXTENSION + +ivorysql=# SELECT * FROM pg_available_extensions WHERE name = 'plpgsql_check'; + name | default_version | installed_version | comment +---------------+-----------------+-------------------+--------------------------------------------------- + plpgsql_check | 2.8 | 2.8 | extended check for plpgsql functions +(1 row) +---- + +== Usage + +=== Check Single Function + +[literal] +---- +-- Create a sample function +CREATE OR REPLACE FUNCTION test_function(p_id integer) +RETURNS text AS $$ +DECLARE + v_name text; + v_unused integer; -- Unused variable +BEGIN + SELECT name INTO v_name FROM users WHERE id = p_id; + RETURN v_naem; -- Spelling error +END; +$$ LANGUAGE plpgsql; + +-- Use plpgsql_check to check the function +SELECT * FROM plpgsql_check_function('test_function(integer)'); +---- + +Example check result: +[literal] +---- + plpgsql_check_function +-------------------------------------------------------------- + error:42601:7:assignment:target variable "v_naem" is undefined + warning:00000:4:DECLARE:unused variable "v_unused" +(2 rows) +---- + +For more detailed usage methods and advanced features, please refer to https://github.com/okbob/plpgsql_check[plpgsql_check official documentation]. +