Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Schemaspy metadata #27

Merged
merged 8 commits into from
Jul 2, 2024
98 changes: 92 additions & 6 deletions src/main/java/org/duckdb/DuckDBDatabaseMetaData.java
Original file line number Diff line number Diff line change
Expand Up @@ -171,27 +171,76 @@ public String getIdentifierQuoteString() throws SQLException {

@Override
public String getSQLKeywords() throws SQLException {
throw new SQLFeatureNotSupportedException("getSQLKeywords");
Statement statement = conn.createStatement();
statement.closeOnCompletion();
ResultSet rs = statement.executeQuery(
"SELECT keyword_name FROM duckdb_keywords()");
StringBuilder sb = new StringBuilder();
while (rs.next()) {
sb.append(rs.getString(1));
sb.append(',');
}
return sb.toString();
}

@Override
public String getNumericFunctions() throws SQLException {
throw new SQLFeatureNotSupportedException("getNumericFunctions");
Statement statement = conn.createStatement();
statement.closeOnCompletion();
ResultSet rs = statement.executeQuery(
"SELECT DISTINCT function_name FROM duckdb_functions() " +
"WHERE parameter_types[1] ='DECIMAL'" +
"OR parameter_types[1] ='DOUBLE'" +
"OR parameter_types[1] ='SMALLINT'" +
"OR parameter_types[1] = 'BIGINT'");
StringBuilder sb = new StringBuilder();
while (rs.next()) {
sb.append(rs.getString(1));
sb.append(',');
}
return sb.toString();
}

@Override
public String getStringFunctions() throws SQLException {
throw new SQLFeatureNotSupportedException("getStringFunctions");
Statement statement = conn.createStatement();
statement.closeOnCompletion();
ResultSet rs = statement.executeQuery(
"SELECT DISTINCT function_name FROM duckdb_functions() WHERE parameter_types[1] = 'VARCHAR'");
StringBuilder sb = new StringBuilder();
while (rs.next()) {
sb.append(rs.getString(1));
sb.append(',');
}
return sb.toString();
}

@Override
public String getSystemFunctions() throws SQLException {
throw new SQLFeatureNotSupportedException("getSystemFunctions");
Statement statement = conn.createStatement();
statement.closeOnCompletion();
ResultSet rs = statement.executeQuery(
"SELECT DISTINCT function_name FROM duckdb_functions() WHERE parameter_types[1] IS NULL");
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

This condition doesn't quite work - probably need to exclude vararg functions somehow?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

select DISTINCT function_name from duckdb_functions() where length(parameter_types) = 0

??

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Probably want to look at the varargs and internal columns?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

It's not used consistently??

D select DISTINCT function_name, parameter_types, varargs from duckdb_functions() where parameter_types[1] is null;
function_name parameter_types varargs
map_from_entries [] ANY
list_median [NULL]
... ... ...

Sometimes, they have a type in the Vargas columns; other times, they have an explicit NULL as the first argument.

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

@Mause is this ok solution given the above, given that vargargs aren't handled consistently?

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Sounds good for now yeah

StringBuilder sb = new StringBuilder();
while (rs.next()) {
sb.append(rs.getString(1));
sb.append(',');
}
return sb.toString();
}

@Override
public String getTimeDateFunctions() throws SQLException {
throw new SQLFeatureNotSupportedException("getTimeDateFunctions");
Statement statement = conn.createStatement();
statement.closeOnCompletion();
ResultSet rs = statement.executeQuery(
"SELECT DISTINCT function_name FROM duckdb_functions() WHERE parameter_types[1] LIKE 'TIME%'");
StringBuilder sb = new StringBuilder();
while (rs.next()) {
sb.append(rs.getString(1));
sb.append(',');
}
return sb.toString();
}

@Override
Expand Down Expand Up @@ -979,7 +1028,44 @@ public ResultSet getTypeInfo() throws SQLException {
@Override
public ResultSet getIndexInfo(String catalog, String schema, String table, boolean unique, boolean approximate)
throws SQLException {
throw new SQLFeatureNotSupportedException("getIndexInfo(");
StringBuilder sb = new StringBuilder();
sb.append("SELECT database_name AS TABLE_CAT " +
", schema_name AS TABLE_SCHEM " +
", table_name AS TABLE_NAME " +
", index_name AS INDEX_NAME " +
", CASE WHEN is_unique THEN 0 ELSE 1 END AS NON_UNIQUE " +
", NULL AS TYPE " +
", NULL AS ORDINAL_POSITION " +
", NULL AS COLUMN_NAME " +
", NULL AS ASC_OR_DESC " +
", NULL AS CARDINALITY " +
", NULL AS PAGES " +
", NULL AS FILTER_CONDITION " +
"FROM duckdb_indexes() WHERE TRUE ");
if (catalog != null) {
sb.append(" AND database_name = ?");
}
if (schema != null) {
sb.append(" AND schema_name = ?");
}
if (table != null) {
sb.append(" AND table_name = ?");
}
sb.append(" ORDER BY TABLE_CAT, TABLE_SCHEM, TABLE_NAME, NON_UNIQUE, INDEX_NAME, ORDINAL_POSITION");
PreparedStatement ps = conn.prepareStatement(sb.toString());
int paramIndex = 1;
if (catalog != null) {
ps.setString(paramIndex++, catalog);
}
if (schema != null) {
ps.setString(paramIndex++, schema);
}
if (table != null) {
ps.setString(paramIndex++, table);
}
ps.closeOnCompletion();
return ps.executeQuery();

}

@Override
Expand Down
74 changes: 74 additions & 0 deletions src/test/java/org/duckdb/TestDuckDBJDBC.java
Original file line number Diff line number Diff line change
Expand Up @@ -4306,6 +4306,80 @@ public static void test_column_metadata() throws Exception {
}
}

public static void test_metadata_get_sql_keywords() throws Exception {
try (Connection conn = DriverManager.getConnection(JDBC_URL)) {
String rs = conn.getMetaData().getSQLKeywords();
String[] keywords = rs.split(",");
List<String> list = asList(keywords);
assertTrue(list.contains("select"));
assertTrue(list.contains("update"));
assertTrue(list.contains("delete"));
assertTrue(list.contains("drop"));
}
}

public static void test_metadata_get_numeric_functions() throws Exception {
try (Connection conn = DriverManager.getConnection(JDBC_URL)) {
String rs = conn.getMetaData().getNumericFunctions();
// print out rs
String[] functions = rs.split(",");
List<String> list = asList(functions);
assertTrue(list.contains("abs"));
assertTrue(list.contains("ceil"));
assertTrue(list.contains("floor"));
assertTrue(list.contains("round"));
}
}

public static void test_metadata_get_string_functions() throws Exception {
try (Connection conn = DriverManager.getConnection(JDBC_URL)) {
String rs = conn.getMetaData().getStringFunctions();
String[] functions = rs.split(",");
List<String> list = asList(functions);
assertTrue(list.contains("md5"));
assertTrue(list.contains("json_keys"));
assertTrue(list.contains("repeat"));
assertTrue(list.contains("from_base64"));
}
}

public static void test_metadata_get_system_functions() throws Exception {
try (Connection conn = DriverManager.getConnection(JDBC_URL)) {
String rs = conn.getMetaData().getSystemFunctions();
String[] functions = rs.split(",");
List<String> list = asList(functions);
assertTrue(list.contains("current_date"));
assertTrue(list.contains("now"));
}
}

public static void test_metadata_get_time_date_functions() throws Exception {
try (Connection conn = DriverManager.getConnection(JDBC_URL)) {
String rs = conn.getMetaData().getTimeDateFunctions();
String[] functions = rs.split(",");
List<String> list = asList(functions);
assertTrue(list.contains("day"));
assertTrue(list.contains("dayname"));
assertTrue(list.contains("timezone_hour"));
}
}

public static void test_metadata_get_index_info() throws Exception {
try (Connection conn = DriverManager.getConnection(JDBC_URL)) {
try (Statement stmt = conn.createStatement()) {
stmt.execute("CREATE TABLE test (id INT PRIMARY KEY, ok INT)");
stmt.execute("CREATE INDEX idx_test_ok ON test(ok)");
}

try (ResultSet rs = conn.getMetaData().getIndexInfo(null, null, "test", false, false)) {
assertTrue(rs.next());
assertEquals(rs.getString("TABLE_NAME"), "test");
assertEquals(rs.getString("INDEX_NAME"), "idx_test_ok");
assertEquals(rs.getBoolean("NON_UNIQUE"), true);
}
}
}

public static void main(String[] args) throws Exception {
System.exit(runTests(args, TestDuckDBJDBC.class, TestExtensionTypes.class));
}
Expand Down
Loading