Change defaults for Connection.tables and ensure that Connection.query recognizes all available tables (#6443)

Closes #6398
This commit is contained in:
Radosław Waśko 2023-04-29 02:13:29 +02:00 committed by GitHub
parent efe904cd9f
commit cdd0065800
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
13 changed files with 142 additions and 42 deletions

View File

@ -1,7 +1,12 @@
from Standard.Base import all
import Standard.Base.Errors.Illegal_Argument.Illegal_Argument
import Standard.Base.Errors.Illegal_State.Illegal_State
import Standard.Base.Runtime.Managed_Resource.Managed_Resource
from Standard.Base.Metadata.Widget import Single_Choice
from Standard.Base.Metadata.Choice import Option
import Standard.Base.Metadata.Display
import Standard.Table.Data.Table.Table as Materialized_Table
import project.Data.SQL_Query.SQL_Query
@ -95,18 +100,27 @@ type Connection
self.jdbc_connection.with_metadata metadata->
read_column metadata.getTableTypes "TABLE_TYPE"
## PRIVATE
Returns a materialized Table of all the matching views and tables.
## Returns a materialized Table of all the matching views and tables.
? Temporary Tables
Note that the temporary tables may be created in a different schema
than the current one, so take this into account when filtering by schema.
Arguments:
- name_like: The table name pattern to search for. Supports SQL wildcards (`%`, `_`). Defaults to `Nothing` which
means all tables are selected.
- database: The database name to search in (default is current database).
- schema: The schema name to search in (defaults to current schema).
- types: The table types to search for. The list of possible values can be obtained using the `table_types` method.
- schema: The schema name to search in (defaults to `Nothing`, meaning all
schemas are searched).
- types: The table types to search for. The list of possible values can
be obtained using the `table_types` method. Defaults to a set of most
commonly used table types, ignoring internal system tables or indices.
- all_fields: Return all the fields in the metadata table.
@types make_table_types_selector
@schema make_schema_selector
tables : Text -> Text -> Text -> Vector -> Boolean -> Materialized_Table
tables self name_like=Nothing database=self.database schema=self.schema types=Nothing all_fields=False =
tables self name_like=Nothing database=self.database schema=Nothing types=self.dialect.default_table_types all_fields=False =
types_array = if types.is_nothing then Nothing else types.to_array
name_map = Map.from_vector [["TABLE_CAT", "Database"], ["TABLE_SCHEM", "Schema"], ["TABLE_NAME", "Name"], ["TABLE_TYPE", "Type"], ["REMARKS", "Description"], ["TYPE_CAT", "Type Database"], ["TYPE_SCHEM", "Type Schema"], ["TYPE_NAME", "Type Name"]]
self.jdbc_connection.with_metadata metadata->
@ -133,11 +147,12 @@ type Connection
raised.
- If provided with a `Table_Name` or a text short-hand and the table is
not found, a `Table_Not_Found` error is raised.
@query make_table_name_selector
query : Text | SQL_Query -> Text -> Table ! Table_Not_Found | SQL_Error
query self query alias="" = case query of
_ : Text ->
result = self.query alias=alias <|
if self.tables.at 'Name' . to_vector . contains query then (SQL_Query.Table_Name query) else
if (all_known_table_names self).contains query then (SQL_Query.Table_Name query) else
SQL_Query.Raw_SQL query
result.catch SQL_Error sql_error->
case self.dialect.is_probably_a_query query of
@ -167,6 +182,7 @@ type Connection
- query: name of the table or sql statement to query.
If supplied as `Text`, the name is checked against the `tables` list to determine if it is a table or a query.
- limit: the maximum number of rows to return.
@query make_table_name_selector
read : Text | SQL_Query -> Integer | Nothing -> Materialized_Table
read self query limit=Nothing =
self.query query . read max_rows=limit
@ -218,3 +234,22 @@ type Connection
drop_table : Text -> Nothing
drop_table self table_name =
self.execute_update (self.dialect.generate_sql (Query.Drop_Table table_name))
## PRIVATE
make_table_types_selector connection =
Single_Choice values=(connection.table_types.map t-> Option t t.pretty)
## PRIVATE
make_schema_selector connection =
schemas_without_nothing = connection.schemas.filter Filter_Condition.Not_Nothing
Single_Choice values=(schemas_without_nothing.map t-> Option t t.pretty)+[Option "any schema" "Nothing"]
## PRIVATE
all_known_table_names connection =
tables = connection.tables name_like=Nothing database=connection.database schema=Nothing types=Nothing all_fields=False
tables.at "Name" . to_vector
## PRIVATE
make_table_name_selector connection =
tables_to_display = connection.tables.at "Name" . to_vector
Single_Choice display=Display.Always values=(tables_to_display.map t-> Option t t.pretty)

View File

@ -187,6 +187,12 @@ type Dialect
_ = operation
Unimplemented.throw "This is an interface only."
## PRIVATE
The default table types to use when listing tables.
default_table_types : Vector Text
default_table_types self =
Unimplemented.throw "This is an interface only."
## PRIVATE
The dialect of SQLite databases.

View File

@ -67,11 +67,15 @@ In_Memory_Table.create_database_table self connection table_name=Nothing primary
sql_type = type_mapping.value_type_to_sql value_type on_problems
sql_type_text = type_mapping.sql_type_to_text sql_type
Pair.new name sql_type_text
create_statement = connection.dialect.generate_sql <|
create_table_statement = connection.dialect.generate_sql <|
Query.Create_Table effective_table_name column_descriptors checked_primary_key temporary
upload_status = create_statement.if_not_error <| connection.jdbc_connection.run_within_transaction <|
Panic.rethrow <| connection.execute_update create_statement
## `create_query.if_not_error` is used to ensure that if there are any
dataflow errors up to this point, we want to propagate them and not
continue. Otherwise, they could 'leak' to `Panic.rethrow` and be wrongly
raised as panics.
upload_status = create_table_statement.if_not_error <| connection.jdbc_connection.run_within_transaction <|
Panic.rethrow <| connection.execute_update create_table_statement
if structure_only.not then
column_names = column_descriptors.map .first
insert_template = make_batched_insert_template connection effective_table_name column_names

View File

@ -13,12 +13,13 @@ import project.Data.SQL_Query.SQL_Query
import project.Data.SQL_Statement.SQL_Statement
import project.Data.SQL_Type.SQL_Type
import project.Data.Table.Table as Database_Table
import project.Internal.IR.Query.Query
import project.Internal.JDBC_Connection
import project.Internal.SQL_Type_Reference.SQL_Type_Reference
from project.Internal.Result_Set import read_column
from project.Connection.Connection import make_table_types_selector, make_schema_selector, make_table_name_selector
from project.Errors import SQL_Error
from project.Internal.Result_Set import read_column
type Postgres_Connection
@ -81,17 +82,27 @@ type Postgres_Connection
table_types : Vector Text
table_types self = self.connection.table_types
## Returns a materialised Table of all the matching views and tables.
## Returns a materialized Table of all the matching views and tables.
? Temporary Tables
Note that the temporary tables may be created in a different schema
than the current one, so take this into account when filtering by schema.
Arguments:
- name_like: The table name pattern to search for. Support SQL wildcards (`%`, `_`).
- name_like: The table name pattern to search for. Supports SQL wildcards (`%`, `_`). Defaults to `Nothing` which
means all tables are selected.
- database: The database name to search in (default is current database).
- schema: The schema name to search in (defaults to current schema).
- types: The table types to search for. The list of values can be obtained using the `table_types` method.
- schema: The schema name to search in (defaults to `Nothing`, meaning all
schemas are searched).
- types: The table types to search for. The list of possible values can
be obtained using the `table_types` method. Defaults to a set of most
commonly used table types, ignoring internal system tables or indices.
- all_fields: Return all the fields in the metadata table.
@types (self-> Single_Choice values=(self.table_types.map t-> Option t t.pretty))
@types make_table_types_selector
@schema make_schema_selector
tables : Text -> Text -> Text -> Vector -> Boolean -> Materialized_Table
tables self name_like=Nothing database=self.database schema=self.schema types=Nothing all_fields=False =
tables self name_like=Nothing database=self.database schema=Nothing types=self.dialect.default_table_types all_fields=False =
self.connection.tables name_like database schema types all_fields
## Set up a query returning a Table object, which can be used to work with data within the database or load it into memory.
@ -100,7 +111,7 @@ type Postgres_Connection
- query: name of the table or sql statement to query.
If supplied as `Text`, the name is checked against the `tables` list to determine if it is a table or a query.
- alias: optionally specify a friendly alias for the query.
@query (self-> Single_Choice display=Display.Always values=(self.tables.at "Name" . to_vector . map t-> Option t t.pretty))
@query make_table_name_selector
query : Text | SQL_Query -> Text -> Database_Table
query self query alias="" = self.connection.query query alias
@ -110,7 +121,7 @@ type Postgres_Connection
- query: name of the table or sql statement to query.
If supplied as `Text`, the name is checked against the `tables` list to determine if it is a table or a query.
- limit: the maximum number of rows to return.
@query (self-> Single_Choice display=Display.Always values=(self.tables.at "Name" . to_vector . map t-> Option t t.pretty))
@query make_table_name_selector
read : Text | SQL_Query -> Integer | Nothing -> Materialized_Table
read self query limit=Nothing = self.connection.read query limit
@ -127,7 +138,6 @@ type Postgres_Connection
execute_update self query =
self.connection.execute_update query
## PRIVATE
Access the dialect.
dialect self = self.connection.dialect
@ -148,7 +158,7 @@ type Postgres_Connection
Arguments:
- url: The URL to connect to.
- properties: A vector of properties for the connection.
- make_new: a function that returns a new connection.
- make_new: a function that returns a new connection.
create : Text -> Vector -> (Text -> Text -> Postgres_Connection) -> Postgres_Connection
create url properties make_new =
jdbc_connection = JDBC_Connection.create url properties

View File

@ -199,6 +199,11 @@ type Postgres_Dialect
is_supported self operation =
self.internal_generator_dialect.is_supported operation
## PRIVATE
The default table types to use when listing tables.
default_table_types : Vector Text
default_table_types self =
["TABLE", "VIEW", "TEMPORARY TABLE", "TEMPORARY VIEW", "MATERIALIZED VIEW", "FOREIGN TABLE", "PARTITIONED TABLE"]
## PRIVATE
make_internal_generator_dialect =

View File

@ -146,3 +146,9 @@ type Redshift_Dialect
is_supported : Text -> Boolean
is_supported self operation =
self.internal_generator_dialect.is_supported operation
## PRIVATE
The default table types to use when listing tables.
default_table_types : Vector Text
default_table_types self =
["TABLE", "VIEW", "TEMPORARY TABLE", "TEMPORARY VIEW", "MATERIALIZED VIEW", "FOREIGN TABLE", "PARTITIONED TABLE"]

View File

@ -9,13 +9,15 @@ import Standard.Table.Data.Table.Table as Materialized_Table
import project.Connection.Connection.Connection
import project.Data.SQL_Query.SQL_Query
import project.Data.SQL_Statement.SQL_Statement
import project.Data.SQL_Type.SQL_Type
import project.Data.Dialect
import project.Data.Table.Table as Database_Table
import project.Internal.IR.Query.Query
import project.Internal.JDBC_Connection
import project.Internal.SQL_Type_Reference.SQL_Type_Reference
import project.Data.SQL_Statement.SQL_Statement
from project.Connection.Connection import make_table_types_selector, make_schema_selector, make_table_name_selector
from project.Errors import SQL_Error
type SQLite_Connection
@ -74,17 +76,27 @@ type SQLite_Connection
table_types : Vector Text
table_types self = self.connection.table_types
## Returns a materialised Table of all the matching views and tables.
## Returns a materialized Table of all the matching views and tables.
? Temporary Tables
Note that the temporary tables may be created in a different schema
than the current one, so take this into account when filtering by schema.
Arguments:
- name_like: The table name pattern to search for. Support SQL wildcards (`%`, `_`).
- name_like: The table name pattern to search for. Supports SQL wildcards (`%`, `_`). Defaults to `Nothing` which
means all tables are selected.
- database: The database name to search in (default is current database).
- schema: The schema name to search in (defaults to current schema).
- types: The table types to search for. The list of values can be obtained using the `table_types` method.
- schema: The schema name to search in (defaults to `Nothing`, meaning all
schemas are searched).
- types: The table types to search for. The list of possible values can
be obtained using the `table_types` method. Defaults to a set of most
commonly used table types, ignoring internal system tables or indices.
- all_fields: Return all the fields in the metadata table.
@types (self-> Single_Choice values=(self.table_types.map t-> Option t t.pretty))
@types make_table_types_selector
@schema make_schema_selector
tables : Text -> Text -> Text -> Vector -> Boolean -> Materialized_Table
tables self name_like=Nothing database=self.database schema=self.schema types=Nothing all_fields=False =
tables self name_like=Nothing database=self.database schema=Nothing types=self.dialect.default_table_types all_fields=False =
self.connection.tables name_like database schema types all_fields
## Set up a query returning a Table object, which can be used to work with data within the database or load it into memory.
@ -93,7 +105,7 @@ type SQLite_Connection
- query: name of the table or sql statement to query.
If supplied as `Text`, the name is checked against the `tables` list to determine if it is a table or a query.
- alias: optionally specify a friendly alias for the query.
@query (self-> Single_Choice display=Display.Always values=(self.tables.at "Name" . to_vector . map t-> Option t t.pretty))
@query make_table_name_selector
query : Text | SQL_Query -> Text -> Database_Table
query self query alias="" = self.connection.query query alias
@ -103,7 +115,7 @@ type SQLite_Connection
- query: name of the table or sql statement to query.
If supplied as `Text`, the name is checked against the `tables` list to determine if it is a table or a query.
- limit: the maximum number of rows to return.
@query (self-> Single_Choice display=Display.Always values=(self.tables.at "Name" . to_vector . map t-> Option t t.pretty))
@query make_table_name_selector
read : Text | SQL_Query -> Integer | Nothing -> Materialized_Table
read self query limit=Nothing = self.connection.read query limit

View File

@ -207,6 +207,12 @@ type SQLite_Dialect
is_supported self operation =
self.internal_generator_dialect.is_supported operation
## PRIVATE
The default table types to use when listing tables.
default_table_types : Vector Text
default_table_types self =
["TABLE", "VIEW", "GLOBAL TEMPORARY"]
## PRIVATE
make_internal_generator_dialect =

View File

@ -30,10 +30,7 @@ spec prefix connection =
run_tests prefix connection upload
run_tests prefix connection upload =
## We have to upload the table as non-temporary, because otherwise it will
not be visible in the list of tables and make `Table.query` confused.
TODO [RW] remove temporary=False once #6398 is done.
t1 = upload "T1" (Table.new [["a", [1, 4]], ["b", [2, 5]], ["c", [3, 6]]]) temporary=False
t1 = upload "T1" (Table.new [["a", [1, 4]], ["b", [2, 5]], ["c", [3, 6]]])
Test.group prefix+"Basic Table Access" <|
Test.specify "should allow to materialize tables and columns into local memory" <|
df = t1.read
@ -99,7 +96,7 @@ run_tests prefix connection upload =
Also, the table name cannot be too long as Postgres truncates at
63 chars (and we append 37 chars of uniqueness suffix) and the
test logic will break then.
t4 = upload 'aSELECT "A",\'B\' FROM t;--' (Table.new [["X", ["a", "B"]], ["Y", [2, 5]]]) temporary=False
t4 = upload 'aSELECT "A",\'B\' FROM t;--' (Table.new [["X", ["a", "B"]], ["Y", [2, 5]]])
t5 = connection.query t4.name
m5 = t5.read
m5.column_names . should_equal ["X", "Y"]

View File

@ -56,6 +56,9 @@ postgres_specific_spec connection db_name setup =
vinfo = Name_Generator.random_name "TestView"
connection.execute_update 'CREATE VIEW "'+vinfo+'" AS SELECT "A" FROM "'+tinfo+'";'
temporary_table = Name_Generator.random_name "TemporaryTable"
(Table.new [["X", [1, 2, 3]]]).create_database_table connection temporary_table temporary=True
Test.specify "should be able to list table types" <|
table_types = connection.table_types
table_types.length . should_not_equal 0
@ -66,8 +69,11 @@ postgres_specific_spec connection db_name setup =
tables = connection.tables
tables.row_count . should_not_equal 0
tables.columns.map .name . should_equal ["Database", "Schema", "Name", "Type", "Description"]
tables.at "Name" . to_vector . contains tinfo . should_be_true
tables.at "Name" . to_vector . contains vinfo . should_be_true
table_names = tables.at "Name" . to_vector
table_names.should_contain tinfo
table_names.should_contain vinfo
table_names.should_contain temporary_table
Test.specify "should be able to filter tables by name" <|
tables = connection.tables tinfo
@ -77,7 +83,11 @@ postgres_specific_spec connection db_name setup =
tables.at "Schema" . to_vector . at 0 . should_equal "public"
tables.at "Name" . to_vector . at 0 . should_equal tinfo
tables.at "Type" . to_vector . at 0 . should_equal "TABLE"
connection.tables "TestT_ble%" . row_count . should_equal 1
connection.tables "Temporary%ble%" . row_count . should_equal 1
connection.tables "Temporary%ble%" . at "Type" . to_vector . should_equal ["TEMPORARY TABLE"]
connection.tables "N_nexistent%" . row_count . should_equal 0
Test.specify "should be able to filter tables by type" <|
tables = connection.tables types=["VIEW"]

View File

@ -40,6 +40,9 @@ sqlite_specific_spec prefix connection =
vinfo = Name_Generator.random_name "TestView"
connection.execute_update 'CREATE VIEW "'+vinfo+'" AS SELECT "A" FROM "'+tinfo+'";'
temporary_table = Name_Generator.random_name "TemporaryTable"
(Table.new [["X", [1, 2, 3]]]).create_database_table connection temporary_table temporary=True
Test.specify "should be able to list table types" <|
table_types = connection.table_types
table_types.length . should_not_equal 0
@ -50,8 +53,11 @@ sqlite_specific_spec prefix connection =
tables = connection.tables
tables.row_count . should_not_equal 0
tables.columns.map .name . should_equal ["Database", "Schema", "Name", "Type", "Description"]
tables.at "Name" . to_vector . contains tinfo . should_be_true
tables.at "Name" . to_vector . contains vinfo . should_be_true
table_names = tables.at "Name" . to_vector
table_names.should_contain tinfo
table_names.should_contain vinfo
table_names.should_contain temporary_table
Test.specify "should be able to filter tables by name" <|
tables = connection.tables tinfo
@ -60,7 +66,11 @@ sqlite_specific_spec prefix connection =
tables.at "Schema" . to_vector . at 0 . should_equal Nothing
tables.at "Name" . to_vector . at 0 . should_equal tinfo
tables.at "Type" . to_vector . at 0 . should_equal "TABLE"
connection.tables "TestT_ble%" . row_count . should_equal 1
connection.tables "Temporary%ble%" . row_count . should_equal 1
connection.tables "Temporary%ble%" . at "Type" . to_vector . should_equal ["GLOBAL TEMPORARY"]
connection.tables "N_nexistent%" . row_count . should_equal 0
Test.specify "should be able to filter tables by type" <|
tables = connection.tables types=["VIEW"]

View File

@ -41,8 +41,7 @@ spec make_new_connection prefix persistent_connector=True =
connection.tables.at "Name" . to_vector . should_contain db_table.name
connection.query db_table.name . at "X" . to_vector . should_equal [1, 2, 3]
postgres_pending = if prefix.contains "Postgre" then "TODO: See issue https://github.com/enso-org/enso/issues/6398"
Test.specify "should include the temporary table in the tables directory" pending=postgres_pending <|
Test.specify "should include the temporary table in the tables directory" <|
db_table = in_memory_table.create_database_table connection (Name_Generator.random_name "temporary_table_1") temporary=True
db_table.at "X" . to_vector . should_equal [1, 2, 3]
connection.tables.at "Name" . to_vector . should_contain db_table.name

View File

@ -25,7 +25,7 @@ spec =
Test.group "Widgets for In-Database Connection with table name sets" <|
Test.specify "works for `query` and `read`" <|
choices = ['sqlite_schema', 'a_table', 'another', 'mock_table'] . map n-> Choice.Option n n.pretty
choices = ['a_table', 'another', 'mock_table'] . map n-> Choice.Option n n.pretty
expect = [["query", Widget.Single_Choice choices Nothing Display.Always]] . to_json
Widgets.get_widget_json connection "query" ["query"] . should_equal expect
Widgets.get_widget_json connection "read" ["query"] . should_equal expect