fix-pgsql-table-ddl

This commit is contained in:
zgq
2024-04-15 13:13:39 +08:00
parent 3b80d15134
commit a738a3f62d
2 changed files with 33 additions and 36 deletions

View File

@ -1,11 +1,5 @@
package ai.chat2db.plugin.postgresql; 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.builder.PostgreSQLSqlBuilder;
import ai.chat2db.plugin.postgresql.type.*; import ai.chat2db.plugin.postgresql.type.*;
import ai.chat2db.server.tools.common.util.EasyCollectionUtils; import ai.chat2db.server.tools.common.util.EasyCollectionUtils;
@ -19,7 +13,13 @@ import com.google.common.collect.Lists;
import jakarta.validation.constraints.NotEmpty; import jakarta.validation.constraints.NotEmpty;
import org.apache.commons.lang3.StringUtils; 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; import static ai.chat2db.spi.util.SortUtils.sortDatabase;
public class PostgreSQLMetaData extends DefaultMetaService implements MetaData { public class PostgreSQLMetaData extends DefaultMetaService implements MetaData {
@ -28,6 +28,7 @@ public class PostgreSQLMetaData extends DefaultMetaService implements MetaData {
private List<String> systemDatabases = Arrays.asList("postgres"); private List<String> systemDatabases = Arrays.asList("postgres");
@Override @Override
public List<Database> databases(Connection connection) { public List<Database> databases(Connection connection) {
List<Database> list = SQLExecutor.getInstance().execute(connection, "SELECT datname FROM pg_database;", resultSet -> { List<Database> 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 databases;
}); });
return sortDatabase(list, systemDatabases,connection); return sortDatabase(list, systemDatabases, connection);
} }
private List<String> systemSchemas = Arrays.asList("pg_toast","pg_temp_1","pg_toast_temp_1","pg_catalog","information_schema"); private List<String> systemSchemas = Arrays.asList("pg_toast", "pg_temp_1", "pg_toast_temp_1", "pg_catalog", "information_schema");
@Override @Override
public List<Schema> schemas(Connection connection, String databaseName) { public List<Schema> schemas(Connection connection, String databaseName) {
List<Schema> schemas = SQLExecutor.getInstance().execute(connection, List<Schema> 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<Schema> databases = new ArrayList<>(); List<Schema> databases = new ArrayList<>();
while (resultSet.next()) { while (resultSet.next()) {
Schema schema = new Schema(); Schema schema = new Schema();
@ -102,15 +103,11 @@ public class PostgreSQLMetaData extends DefaultMetaService implements MetaData {
@Override @Override
public String tableDDL(Connection connection, String databaseName, String schemaName, String tableName) { public String tableDDL(Connection connection, String databaseName, String schemaName, String tableName) {
SQLExecutor.getInstance().execute(connection, FUNCTION_SQL, resultSet -> null); SQLExecutor.getInstance().execute(connection, TABLE_DEF_FUNCTION_SQL, resultSet -> null);
String ddlSql = "select pg_get_tabledef" + "(" + "'" + schemaName + "'" + "," + "'" + tableName + "'" + "," + "false" + "," + "'" + "COMMENTS" + "'" + ")" + ";"; String ddlSql = String.format("select * from pg_get_tabledef('%s','%s',false,'COMMENTS') as ddl;", schemaName, tableName);
return SQLExecutor.getInstance().execute(connection, ddlSql, resultSet -> { return SQLExecutor.getInstance().execute(connection, ddlSql, resultSet -> {
try { if (resultSet.next()) {
if (resultSet.next()) { return resultSet.getString("ddl");
return resultSet.getString(1);
}
} catch (SQLException e) {
throw new RuntimeException(e);
} }
return null; return null;
}); });
@ -226,7 +223,7 @@ public class PostgreSQLMetaData extends DefaultMetaService implements MetaData {
TableIndex tableIndex = map.get(keyName); TableIndex tableIndex = map.get(keyName);
if (tableIndex != null) { if (tableIndex != null) {
List<TableIndexColumn> columnList = tableIndex.getColumnList(); List<TableIndexColumn> columnList = tableIndex.getColumnList();
if(columnList == null){ if (columnList == null) {
columnList = new ArrayList<>(); columnList = new ArrayList<>();
tableIndex.setColumnList(columnList); tableIndex.setColumnList(columnList);
} }

View File

@ -1,14 +1,14 @@
package ai.chat2db.plugin.postgresql.consts; package ai.chat2db.plugin.postgresql.consts;
public class SQLConst { public class SQLConst {
public static String FUNCTION_SQL = public static String TABLE_DEF_FUNCTION_SQL =
""" """
DROP TYPE IF EXISTS public.tabledefs CASCADE; DROP TYPE IF EXISTS tabledefs CASCADE;
CREATE TYPE public.tabledefs AS ENUM ('PKEY_INTERNAL','PKEY_EXTERNAL','FKEYS_INTERNAL', 'FKEYS_EXTERNAL', 'COMMENTS', 'FKEYS_NONE', 'INCLUDE_TRIGGERS', 'NO_TRIGGERS'); 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'); -- SELECT * FROM pg_get_coldef('sample','orders','id');
-- DROP FUNCTION public.pg_get_coldef(text,text,text,boolean); -- DROP FUNCTION pg_get_coldef(text,text,text,boolean);
CREATE OR REPLACE FUNCTION public.pg_get_coldef( CREATE OR REPLACE FUNCTION pg_get_coldef(
in_schema text, in_schema text,
in_table text, in_table text,
in_column text, in_column text,
@ -57,13 +57,13 @@ public class SQLConst {
END; END;
$$; $$;
-- SELECT * FROM public.pg_get_tabledef('sample', 'address', false); -- SELECT * FROM pg_get_tabledef('sample', 'address', false);
DROP FUNCTION IF EXISTS public.pg_get_tabledef(character varying,character varying,boolean,tabledefs[]); DROP FUNCTION IF EXISTS pg_get_tabledef(character varying,character varying,boolean,tabledefs[]);
CREATE OR REPLACE FUNCTION public.pg_get_tabledef( CREATE OR REPLACE FUNCTION pg_get_tabledef(
in_schema varchar, in_schema varchar,
in_table varchar, in_table varchar,
_verbose boolean, _verbose boolean,
VARIADIC arr public.tabledefs[] DEFAULT '{}':: public.tabledefs[] VARIADIC arr tabledefs[] DEFAULT '{}':: tabledefs[]
) )
RETURNS text RETURNS text
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
@ -111,12 +111,12 @@ public class SQLConst {
fkcnt int := 0; fkcnt int := 0;
trigcnt int := 0; trigcnt int := 0;
cmtcnt int := 0; cmtcnt int := 0;
pktype public.tabledefs := 'PKEY_INTERNAL'; pktype tabledefs := 'PKEY_INTERNAL';
fktype public.tabledefs := 'FKEYS_INTERNAL'; fktype tabledefs := 'FKEYS_INTERNAL';
trigtype public.tabledefs := 'NO_TRIGGERS'; trigtype tabledefs := 'NO_TRIGGERS';
arglen integer; arglen integer;
vargs text; vargs text;
avarg public.tabledefs; avarg tabledefs;
-- exception variables -- exception variables
v_ret text; 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(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; 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; 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 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; RAISE NOTICE 'DEBUG tabledef: %', v_table_ddl;
END IF; END IF;
@ -351,12 +351,12 @@ public class SQLConst {
v_temp = v_colrec.udt_schema || '.' || v_colrec.udt_name; v_temp = v_colrec.udt_schema || '.' || v_colrec.udt_name;
ELSEIF v_colrec.data_type = 'ARRAY' THEN ELSEIF v_colrec.data_type = 'ARRAY' THEN
-- Issue#6 fix: handle arrays -- 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 -- 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 -- 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 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 -- 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 ELSE
v_temp = v_colrec.data_type; v_temp = v_colrec.data_type;
END IF; END IF;