Skip to content

Commit

Permalink
Postgres imports: Hide postgis internal views
Browse files Browse the repository at this point in the history
Re #434

Hides these views/tables from `kart import '<postgres-url>'`:

```
 extname | extschema |      relname      | relkind
---------+-----------+-------------------+---------
 postgis | public    | spatial_ref_sys   | r
 postgis | public    | geography_columns | v
 postgis | public    | geometry_columns  | v
 postgis | public    | raster_columns    | v
 postgis | public    | raster_overviews  | v
```

These aren't importable things and they just cause potential problems,
especially when used with `--all-tables` (but they are noisy when
listing/prompting for tables also)
  • Loading branch information
craigds committed Jun 4, 2021
1 parent 46f4406 commit 42bf423
Show file tree
Hide file tree
Showing 4 changed files with 62 additions and 27 deletions.
1 change: 1 addition & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,7 @@ _When adding new entries to the changelog, please include issue/PR numbers where
* A few bugfixes involving accurately roundtripping boolean and blob types through different working copy types.
* Bugfix: 3D and 4D geometries are now properly roundtripped through SQL Server working copy.
* Fix help text for discarding changes to refer to `kart restore` instead of `kart reset`, as `kart restore` is now the simplest way to discard changes. [#426](https://github.com/koordinates/kart/issues/426)
* `import`: PostGIS internal views/tables are no longer listed by `--list` or imported by `--all-tables`, and can't be imported by name either. [#439](https://github.com/koordinates/kart/issues/439)

### Calculating feature counts for diffs

Expand Down
49 changes: 26 additions & 23 deletions kart/sqlalchemy/postgis.py
Original file line number Diff line number Diff line change
Expand Up @@ -31,31 +31,34 @@ def _on_checkout(dbapi_connection, connection_record, connection_proxy):
@classmethod
def list_tables(cls, sess, db_schema=None):
if db_schema is not None:
r = sess.execute(
sqlalchemy.text(
"""
SELECT table_name as name,
obj_description(format('%s.%s', table_schema, table_name)::regclass::oid, 'pg_class') as title
FROM information_schema.tables WHERE table_schema = :db_schema
ORDER BY name;
"""
),
{"db_schema": db_schema},
)
name_clause = "c.relname"
schema_clause = "n.nspname = :db_schema"
params = {"db_schema": db_schema}
else:
r = sess.execute(
sqlalchemy.text(
"""
SELECT format('%s.%s', table_schema, table_name) as name,
obj_description(format('%s.%s', table_schema, table_name)::regclass::oid, 'pg_class') as title
FROM information_schema.tables
WHERE table_schema NOT IN ('information_schema', 'pg_catalog', 'tiger', 'topology')
ORDER BY name;
"""
)
)
name_clause = "format('%s.%s', n.nspname, c.relname)"
schema_clause = "n.nspname NOT IN ('information_schema', 'pg_catalog', 'tiger', 'topology')"
params = {}

return {row['name']: row['title'] for row in r}
r = sess.execute(
sqlalchemy.text(
f"""
SELECT {name_clause} as name, obj_description(c.oid, 'pg_class') as title
FROM pg_catalog.pg_class c
INNER JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE c.relkind IN ('r', 'v') AND {schema_clause}
AND c.oid NOT IN (
SELECT d.objid
FROM pg_catalog.pg_extension AS e
INNER JOIN pg_catalog.pg_depend AS d ON (d.refobjid = e.oid)
WHERE d.deptype = 'e'
AND e.extname = 'postgis'
)
ORDER BY {name_clause};
"""
),
params,
)
return {row["name"]: row["title"] for row in r}

@classmethod
def db_schema_searchpath(cls, sess):
Expand Down
4 changes: 2 additions & 2 deletions kart/sqlalchemy_import_source.py
Original file line number Diff line number Diff line change
Expand Up @@ -155,10 +155,10 @@ def validate_table(self, table):
if table in all_tables:
if (
self.db_schema is None
and '.' in table
and "." in table
and self.db_type is not DbType.GPKG
):
db_schema, table = table.split('.', maxsplit=1)
db_schema, table = table.split(".", maxsplit=1)
return db_schema, table
else:
return self.db_schema, table
Expand Down
35 changes: 33 additions & 2 deletions tests/test_import_source.py
Original file line number Diff line number Diff line change
Expand Up @@ -2,6 +2,8 @@

from osgeo import gdal

import pytest

from kart.ogr_import_source import postgres_url_to_ogr_conn_str
from kart.repo import KartRepo

Expand All @@ -15,8 +17,8 @@ def _dataset_col_types(dataset):
return cols


def test_import_various_field_types(tmp_path, postgis_db, cli_runner):
# Using postgres here because it has the best type preservation
@pytest.fixture
def postgres_table_with_types(postgis_db):
with postgis_db.connect() as conn:
conn.execute(
"""
Expand All @@ -38,6 +40,17 @@ def test_import_various_field_types(tmp_path, postgis_db, cli_runner):
);
"""
)
yield
with postgis_db.connect() as conn:
conn.execute(
"""
DROP TABLE IF EXISTS typoes;
"""
)


def test_import_various_field_types(tmp_path, postgres_table_with_types, cli_runner):
# Using postgres here because it has the best type preservation

r = cli_runner.invoke(["init", str(tmp_path / "repo1")])
assert r.exit_code == 0, r.stderr
Expand Down Expand Up @@ -115,3 +128,21 @@ def test_import_various_field_types(tmp_path, postgis_db, cli_runner):
"reel": {"dataType": "float", "size": 64},
"tumeric": {"dataType": "float", "size": 64},
}


def test_list_postgres_tables(postgis_db, postgres_table_with_types, cli_runner):
# Using postgres here because it has the best type preservation
r = cli_runner.invoke(["import", "--list", os.environ["KART_POSTGRES_URL"]])
assert r.exit_code == 0, r.stderr

# NOTE: these tables are intentionally absent:
# ' public.geography_columns',
# ' public.geometry_columns',
# ' public.spatial_ref_sys',
assert r.stdout.splitlines() == ["Tables found:", " public.typoes"]

r = cli_runner.invoke(
["import", "--list", os.environ["KART_POSTGRES_URL"] + "/public"]
)
assert r.exit_code == 0, r.stderr
assert r.stdout.splitlines() == ["Tables found:", " typoes"]

0 comments on commit 42bf423

Please sign in to comment.