From a738a3f62d3ab6b337a8e270011a4baa96ff34e8 Mon Sep 17 00:00:00 2001 From: zgq <203083679@qq.com> Date: Mon, 15 Apr 2024 13:13:39 +0800 Subject: [PATCH] fix-pgsql-table-ddl --- .../plugin/postgresql/PostgreSQLMetaData.java | 35 +++++++++---------- .../plugin/postgresql/consts/SQLConst.java | 34 +++++++++--------- 2 files changed, 33 insertions(+), 36 deletions(-) diff --git a/chat2db-server/chat2db-plugins/chat2db-postgresql/src/main/java/ai/chat2db/plugin/postgresql/PostgreSQLMetaData.java b/chat2db-server/chat2db-plugins/chat2db-postgresql/src/main/java/ai/chat2db/plugin/postgresql/PostgreSQLMetaData.java index 5e9d6897..5ecf17ab 100644 --- a/chat2db-server/chat2db-plugins/chat2db-postgresql/src/main/java/ai/chat2db/plugin/postgresql/PostgreSQLMetaData.java +++ b/chat2db-server/chat2db-plugins/chat2db-postgresql/src/main/java/ai/chat2db/plugin/postgresql/PostgreSQLMetaData.java @@ -1,11 +1,5 @@ package ai.chat2db.plugin.postgresql; -import java.sql.Connection; -import java.sql.ResultSet; -import java.sql.SQLException; -import java.util.*; -import java.util.stream.Collectors; - import ai.chat2db.plugin.postgresql.builder.PostgreSQLSqlBuilder; import ai.chat2db.plugin.postgresql.type.*; import ai.chat2db.server.tools.common.util.EasyCollectionUtils; @@ -19,7 +13,13 @@ import com.google.common.collect.Lists; import jakarta.validation.constraints.NotEmpty; import org.apache.commons.lang3.StringUtils; -import static ai.chat2db.plugin.postgresql.consts.SQLConst.FUNCTION_SQL; +import java.sql.Connection; +import java.sql.ResultSet; +import java.sql.SQLException; +import java.util.*; +import java.util.stream.Collectors; + +import static ai.chat2db.plugin.postgresql.consts.SQLConst.TABLE_DEF_FUNCTION_SQL; import static ai.chat2db.spi.util.SortUtils.sortDatabase; public class PostgreSQLMetaData extends DefaultMetaService implements MetaData { @@ -28,6 +28,7 @@ public class PostgreSQLMetaData extends DefaultMetaService implements MetaData { private List systemDatabases = Arrays.asList("postgres"); + @Override public List databases(Connection connection) { List list = SQLExecutor.getInstance().execute(connection, "SELECT datname FROM pg_database;", resultSet -> { @@ -47,15 +48,15 @@ public class PostgreSQLMetaData extends DefaultMetaService implements MetaData { } return databases; }); - return sortDatabase(list, systemDatabases,connection); + return sortDatabase(list, systemDatabases, connection); } - private List systemSchemas = Arrays.asList("pg_toast","pg_temp_1","pg_toast_temp_1","pg_catalog","information_schema"); + private List systemSchemas = Arrays.asList("pg_toast", "pg_temp_1", "pg_toast_temp_1", "pg_catalog", "information_schema"); @Override public List schemas(Connection connection, String databaseName) { List schemas = SQLExecutor.getInstance().execute(connection, - "SELECT catalog_name, schema_name FROM information_schema.schemata;", resultSet -> { + "SELECT catalog_name, schema_name FROM information_schema.schemata;", resultSet -> { List databases = new ArrayList<>(); while (resultSet.next()) { Schema schema = new Schema(); @@ -102,15 +103,11 @@ public class PostgreSQLMetaData extends DefaultMetaService implements MetaData { @Override public String tableDDL(Connection connection, String databaseName, String schemaName, String tableName) { - SQLExecutor.getInstance().execute(connection, FUNCTION_SQL, resultSet -> null); - String ddlSql = "select pg_get_tabledef" + "(" + "'" + schemaName + "'" + "," + "'" + tableName + "'" + "," + "false" + "," + "'" + "COMMENTS" + "'" + ")" + ";"; + SQLExecutor.getInstance().execute(connection, TABLE_DEF_FUNCTION_SQL, resultSet -> null); + String ddlSql = String.format("select * from pg_get_tabledef('%s','%s',false,'COMMENTS') as ddl;", schemaName, tableName); return SQLExecutor.getInstance().execute(connection, ddlSql, resultSet -> { - try { - if (resultSet.next()) { - return resultSet.getString(1); - } - } catch (SQLException e) { - throw new RuntimeException(e); + if (resultSet.next()) { + return resultSet.getString("ddl"); } return null; }); @@ -226,7 +223,7 @@ public class PostgreSQLMetaData extends DefaultMetaService implements MetaData { TableIndex tableIndex = map.get(keyName); if (tableIndex != null) { List columnList = tableIndex.getColumnList(); - if(columnList == null){ + if (columnList == null) { columnList = new ArrayList<>(); tableIndex.setColumnList(columnList); } diff --git a/chat2db-server/chat2db-plugins/chat2db-postgresql/src/main/java/ai/chat2db/plugin/postgresql/consts/SQLConst.java b/chat2db-server/chat2db-plugins/chat2db-postgresql/src/main/java/ai/chat2db/plugin/postgresql/consts/SQLConst.java index 276f5961..05327bc9 100644 --- a/chat2db-server/chat2db-plugins/chat2db-postgresql/src/main/java/ai/chat2db/plugin/postgresql/consts/SQLConst.java +++ b/chat2db-server/chat2db-plugins/chat2db-postgresql/src/main/java/ai/chat2db/plugin/postgresql/consts/SQLConst.java @@ -1,14 +1,14 @@ package ai.chat2db.plugin.postgresql.consts; public class SQLConst { - public static String FUNCTION_SQL = + public static String TABLE_DEF_FUNCTION_SQL = """ - DROP TYPE IF EXISTS public.tabledefs CASCADE; - CREATE TYPE public.tabledefs AS ENUM ('PKEY_INTERNAL','PKEY_EXTERNAL','FKEYS_INTERNAL', 'FKEYS_EXTERNAL', 'COMMENTS', 'FKEYS_NONE', 'INCLUDE_TRIGGERS', 'NO_TRIGGERS'); + DROP TYPE IF EXISTS tabledefs CASCADE; + CREATE TYPE tabledefs AS ENUM ('PKEY_INTERNAL','PKEY_EXTERNAL','FKEYS_INTERNAL', 'FKEYS_EXTERNAL', 'COMMENTS', 'FKEYS_NONE', 'INCLUDE_TRIGGERS', 'NO_TRIGGERS'); - -- SELECT * FROM public.pg_get_coldef('sample','orders','id'); - -- DROP FUNCTION public.pg_get_coldef(text,text,text,boolean); - CREATE OR REPLACE FUNCTION public.pg_get_coldef( + -- SELECT * FROM pg_get_coldef('sample','orders','id'); + -- DROP FUNCTION pg_get_coldef(text,text,text,boolean); + CREATE OR REPLACE FUNCTION pg_get_coldef( in_schema text, in_table text, in_column text, @@ -57,13 +57,13 @@ public class SQLConst { END; $$; - -- SELECT * FROM public.pg_get_tabledef('sample', 'address', false); - DROP FUNCTION IF EXISTS public.pg_get_tabledef(character varying,character varying,boolean,tabledefs[]); - CREATE OR REPLACE FUNCTION public.pg_get_tabledef( + -- SELECT * FROM pg_get_tabledef('sample', 'address', false); + DROP FUNCTION IF EXISTS pg_get_tabledef(character varying,character varying,boolean,tabledefs[]); + CREATE OR REPLACE FUNCTION pg_get_tabledef( in_schema varchar, in_table varchar, _verbose boolean, - VARIADIC arr public.tabledefs[] DEFAULT '{}':: public.tabledefs[] + VARIADIC arr tabledefs[] DEFAULT '{}':: tabledefs[] ) RETURNS text LANGUAGE plpgsql VOLATILE @@ -111,12 +111,12 @@ public class SQLConst { fkcnt int := 0; trigcnt int := 0; cmtcnt int := 0; - pktype public.tabledefs := 'PKEY_INTERNAL'; - fktype public.tabledefs := 'FKEYS_INTERNAL'; - trigtype public.tabledefs := 'NO_TRIGGERS'; + pktype tabledefs := 'PKEY_INTERNAL'; + fktype tabledefs := 'FKEYS_INTERNAL'; + trigtype tabledefs := 'NO_TRIGGERS'; arglen integer; vargs text; - avarg public.tabledefs; + avarg tabledefs; -- exception variables v_ret text; @@ -323,7 +323,7 @@ public class SQLConst { -- SELECT pg_get_serial_sequence(v_qualified, v_colrec.column_name) into v_temp; SELECT pg_get_serial_sequence(quote_ident(in_schema) || '.' || quote_ident(in_table), v_colrec.column_name) into v_temp; IF v_temp IS NULL THEN v_temp = 'NA'; END IF; - SELECT public.pg_get_coldef(in_schema, in_table,v_colrec.column_name) INTO v_diag1; + SELECT pg_get_coldef(in_schema, in_table,v_colrec.column_name) INTO v_diag1; RAISE NOTICE 'DEBUG table: % Column: % datatype: % Serial=% serialval=% coldef=%', v_qualified, v_colrec.column_name, v_colrec.data_type, bSerial, v_temp, v_diag1; RAISE NOTICE 'DEBUG tabledef: %', v_table_ddl; END IF; @@ -351,12 +351,12 @@ public class SQLConst { v_temp = v_colrec.udt_schema || '.' || v_colrec.udt_name; ELSEIF v_colrec.data_type = 'ARRAY' THEN -- Issue#6 fix: handle arrays - v_temp = public.pg_get_coldef(in_schema, in_table,v_colrec.column_name); + v_temp = pg_get_coldef(in_schema, in_table,v_colrec.column_name); -- v17 fix: handle case-sensitive for pg_get_serial_sequence that requires SQL Identifier handling -- WHEN pg_get_serial_sequence(v_qualified, v_colrec.column_name) IS NOT NULL ELSEIF pg_get_serial_sequence(quote_ident(in_schema) || '.' || quote_ident(in_table), v_colrec.column_name) IS NOT NULL THEN -- Issue#8 fix: handle serial. Note: NOT NULL is implied so no need to declare it explicitly - v_temp = public.pg_get_coldef(in_schema, in_table,v_colrec.column_name); + v_temp = pg_get_coldef(in_schema, in_table,v_colrec.column_name); ELSE v_temp = v_colrec.data_type; END IF;