From c5bf2fbfc57fa7dd2dc18b844b8ead3c27899d94 Mon Sep 17 00:00:00 2001 From: Ning Sun Date: Mon, 9 Dec 2024 12:43:11 +0800 Subject: [PATCH 1/2] doc: postgres foreign data wrapper --- docs/greptimecloud/integrations/postgresql.md | 15 +++ docs/user-guide/protocols/postgresql.md | 103 +++++++++++++++++- .../greptimecloud/integrations/postgresql.md | 15 +++ .../user-guide/protocols/postgresql.md | 101 ++++++++++++++++- 4 files changed, 232 insertions(+), 2 deletions(-) diff --git a/docs/greptimecloud/integrations/postgresql.md b/docs/greptimecloud/integrations/postgresql.md index 99eca8e482..c9549e5e31 100644 --- a/docs/greptimecloud/integrations/postgresql.md +++ b/docs/greptimecloud/integrations/postgresql.md @@ -48,3 +48,18 @@ If you are using clients from Python, you might be able to use following URL ```text postgresql://:@:4003/ ``` + +## Postgres Foreign Data Wrapper + +Configure your GreptimeCloud instance as Postgres FDW. Change server name and +username to your own. + +```sql +CREATE SERVER greptimedb +FOREIGN DATA WRAPPER postgres_fdw +OPTIONS (host '', dbname '', port '4003'); + +CREATE USER MAPPING FOR postgres +SERVER greptimedb +OPTIONS (user '', password ''); +``` diff --git a/docs/user-guide/protocols/postgresql.md b/docs/user-guide/protocols/postgresql.md index ba37620b6d..27005d82b3 100644 --- a/docs/user-guide/protocols/postgresql.md +++ b/docs/user-guide/protocols/postgresql.md @@ -48,7 +48,7 @@ SHOW VARIABLES time_zone; ``` ```sql - TIME_ZONE + TIME_ZONE ----------- UTC ``` @@ -61,3 +61,104 @@ SET TIMEZONE TO '+1:00' For information on how the time zone affects data inserts and queries, please refer to the SQL documents in the [Ingest Data](/user-guide/ingest-data/for-iot/sql.md#time-zone) and [Query Data](/user-guide/query-data/sql.md#time-zone) sections. +## Foreign Data Wrapper + +GreptimeDB can be configured as a foreign data server for Postgres' built-in +[FDW extension](https://www.postgresql.org/docs/current/postgres-fdw.html). This +allows user to query GreptimeDB tables seamlessly from Postgres server. It's +also possible to join Postgres tables with GreptimeDB tables. + +For example, your IoT metadata, like device information, is stored in a +relational data model in Postgres. It's possible to use filter queries to find +out device IDs and join with time-series data from GreptimeDB. + +### Setup + +To setup GreptimeDB for Postgres FDW, make sure you enabled postgres protocol +support in GreptimeDB and it's accessible from your Postgres server. + +To create and configuration GreptimeDB in Postgres, first enable the +`postgres_fdw` entension. + +```sql +CREATE EXTENSION postgres_fdw; +``` + +Add GreptimeDB instance as remote server. + +```sql +CREATE SERVER greptimedb +FOREIGN DATA WRAPPER postgres_fdw +OPTIONS (host 'greptimedb_host', dbname 'public', port '4003'); +``` + +Configure user mapping for Postgres user and GreptimeDB user. This step is +required. But if you don't have authentication enabled in GreptimeDB OSS +version, just fill the credential with random data. + +```sql +CREATE USER MAPPING FOR postgres +SERVER greptimedb +OPTIONS (user 'greptime', password '...'); +``` + +Create foreign table in Postgres to map GreptimeDB's schema. Note that you will +need to use Postgres' corresponding data types for GreptimeDB's. + +For GreptimeDB's tables + +```sql +CREATE TABLE grpc_latencies ( + ts TIMESTAMP TIME INDEX, + host STRING, + method_name STRING, + latency DOUBLE, + PRIMARY KEY (host, method_name) +) with('append_mode'='true'); + +CREATE TABLE app_logs ( + ts TIMESTAMP TIME INDEX, + host STRING, + api_path STRING FULLTEXT, + log_level STRING, + log STRING FULLTEXT, + PRIMARY KEY (host, log_level) +) with('append_mode'='true'); +``` + +You will need to define them like this in Postgres. + +```sql +CREATE FOREIGN TABLE ft_grpc_latencies ( + ts TIMESTAMP, + host VARCHAR, + method_name VARCHAR, + latency DOUBLE precision +) +SERVER greptimedb +OPTIONS (table_name 'grpc_latencies'); + +CREATE FOREIGN TABLE ft_app_logs ( + ts TIMESTAMP, + host VARCHAR, + api_path VARCHAR, + log_level VARCHAR, + log VARCHAR +) +SERVER greptimedb +OPTIONS (table_name 'app_logs'); +``` + +You can now send query from Postgres. It's also possible to use functions that +are available in both Postgres and GreptimeDB, like `date_trunc`. + +```sql +SELECT * FROM ft_app_logs ORDER BY ts DESC LIMIT 100; + +SELECT + date_trunc('MINUTE', ts) as t, + host, + avg(latency), + count(latency) +FROM ft_grpc_latencies GROUP BY host, t; +``` diff --git a/i18n/zh/docusaurus-plugin-content-docs/current/greptimecloud/integrations/postgresql.md b/i18n/zh/docusaurus-plugin-content-docs/current/greptimecloud/integrations/postgresql.md index fe1df731aa..0d03204ac4 100644 --- a/i18n/zh/docusaurus-plugin-content-docs/current/greptimecloud/integrations/postgresql.md +++ b/i18n/zh/docusaurus-plugin-content-docs/current/greptimecloud/integrations/postgresql.md @@ -45,3 +45,18 @@ jdbc:postgresql://:4003/?user=&password=&ssl=t ``` postgresql://:@:4003/ ``` + +## Postgres 外部表 + +将 GreptimeCloud 实例配置外 Postgres 外部数据源。注意依据你的配置修改下方的服务 +器名和用户名 。 + +```sql +CREATE SERVER greptimedb +FOREIGN DATA WRAPPER postgres_fdw +OPTIONS (host '', dbname '', port '4003'); + +CREATE USER MAPPING FOR postgres +SERVER greptimedb +OPTIONS (user '', password ''); +``` diff --git a/i18n/zh/docusaurus-plugin-content-docs/current/user-guide/protocols/postgresql.md b/i18n/zh/docusaurus-plugin-content-docs/current/user-guide/protocols/postgresql.md index 64e343a56e..8581db5dad 100644 --- a/i18n/zh/docusaurus-plugin-content-docs/current/user-guide/protocols/postgresql.md +++ b/i18n/zh/docusaurus-plugin-content-docs/current/user-guide/protocols/postgresql.md @@ -47,7 +47,7 @@ SHOW VARIABLES time_zone; ``` ```sql - TIME_ZONE + TIME_ZONE ----------- UTC ``` @@ -59,3 +59,102 @@ SET TIMEZONE TO '+1:00' ``` 有关时区如何影响数据的插入和查询,请参考[写入数据](/user-guide/ingest-data/for-iot/sql.md#时区)和[查询数据](/user-guide/query-data/sql.md#时区)中的 SQL 文档。 + +## 外部数据 + +利用 Postgres 的 [FDW 扩 +展](https://www.postgresql.org/docs/current/postgres-fdw.html), GreptimeDB 可以 +被配置为 Postgres 的外部数据服务。 这使得我们可以用 Postgres 服务器上无缝地查询 +GreptimeDB 里的时序数据,并且可以利用 join 查询同时关联两边的数据。 + +举个例子,类似设备信息类的物联网元数据,通常存储在 Postgres 这样的关系型数据库中。 +现在我们可以利用这个功能,先在 Postgres 利用关系查询过滤出满足条件的设备 ID,然 +后直接关联的 GreptimeDB 承载的外部表上查询设备的时序数据。 + +### 配置 + +首先要确保 GreptimeDB 打开了 Postgres 协议,并且她可以被 Postgres 服务器访问到。 + +在 Postgres 上开启 fdw 扩展。 + +```sql +CREATE EXTENSION postgres_fdw; +``` + +将 GreptimeDB 添加为远程服务器。 + +```sql +CREATE SERVER greptimedb +FOREIGN DATA WRAPPER postgres_fdw +OPTIONS (host 'greptimedb_host', dbname 'public', port '4003'); +``` + +把 Postgres 用户映射到 GreptimeDB 上。这一步是必须步骤。如果你没有在 GreptimeDB +开源版本上启用认证,这里可以填写任意的认证信息。 + +```sql +CREATE USER MAPPING FOR postgres +SERVER greptimedb +OPTIONS (user 'greptime', password '...'); +``` + +在 Postgres 创建与 GreptimeDB 映射的外部表。这一步是为了告知 Postgres 相应表的数 +据结构。注意需要将 GreptimeDB 的数据类型映射到 Postgres 类型上。 + +对于这样的 GreptimeDB 表: + +```sql +CREATE TABLE grpc_latencies ( + ts TIMESTAMP TIME INDEX, + host STRING, + method_name STRING, + latency DOUBLE, + PRIMARY KEY (host, method_name) +) with('append_mode'='true'); + +CREATE TABLE app_logs ( + ts TIMESTAMP TIME INDEX, + host STRING, + api_path STRING FULLTEXT, + log_level STRING, + log STRING FULLTEXT, + PRIMARY KEY (host, log_level) +) with('append_mode'='true'); +``` + +其 Postgres 外部表定义如下: + +```sql +CREATE FOREIGN TABLE ft_grpc_latencies ( + ts TIMESTAMP, + host VARCHAR, + method_name VARCHAR, + latency DOUBLE precision +) +SERVER greptimedb +OPTIONS (table_name 'grpc_latencies'); + +CREATE FOREIGN TABLE ft_app_logs ( + ts TIMESTAMP, + host VARCHAR, + api_path VARCHAR, + log_level VARCHAR, + log VARCHAR +) +SERVER greptimedb +OPTIONS (table_name 'app_logs'); +``` + +至此你可以通过 Postgres 发起查询。并且可以使用一些同时存在在 GreptimeDB 和 +Postgres 上的函数,如 `date_trunc` 等。 + +```sql +SELECT * FROM ft_app_logs ORDER BY ts DESC LIMIT 100; + +SELECT + date_trunc('MINUTE', ts) as t, + host, + avg(latency), + count(latency) +FROM ft_grpc_latencies GROUP BY host, t; +``` From cb4f8b0efcf067c5f7c7ffed2f5f2b717ed095b5 Mon Sep 17 00:00:00 2001 From: Ning Sun Date: Mon, 9 Dec 2024 12:47:27 +0800 Subject: [PATCH 2/2] fix: typo --- docs/user-guide/protocols/postgresql.md | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/docs/user-guide/protocols/postgresql.md b/docs/user-guide/protocols/postgresql.md index 27005d82b3..2f9f931d09 100644 --- a/docs/user-guide/protocols/postgresql.md +++ b/docs/user-guide/protocols/postgresql.md @@ -78,7 +78,7 @@ To setup GreptimeDB for Postgres FDW, make sure you enabled postgres protocol support in GreptimeDB and it's accessible from your Postgres server. To create and configuration GreptimeDB in Postgres, first enable the -`postgres_fdw` entension. +`postgres_fdw` extension. ```sql CREATE EXTENSION postgres_fdw;