From d503ea060dbe60e52e6346dd3b04e0e812dbfcd4 Mon Sep 17 00:00:00 2001 From: Aaron Straup Cope Date: Sat, 14 Dec 2024 13:12:18 -0800 Subject: [PATCH] Add support for Postgres (#1) * block out pgsql tables * can create pgsql tables, not tried indexing yet * snapshot: index ancestors and geojson in postgres * make concordances work * index geometries in pgsql * pgsql: index names, properties, spelunker * pgsql: index spr and supersedes * wrangle -spatial-tables for postgres * update README --------- Co-authored-by: thisisaaronland --- README.md | 7 +- app/sql/index/app.go | 21 +- app/sql/tables/create/create.go | 293 ++++++++++++++++++ app/sql/tables/create/flags.go | 72 +++++ cmd/wof-sql-index/main.go | 4 +- go.mod | 2 +- go.sum | 4 +- sql/tables/ancestors.go | 41 ++- sql/tables/ancestors.postgres.schema | 8 + sql/tables/concordances.go | 33 +- sql/tables/concordances.postgres.schema | 9 + sql/tables/geojson.go | 46 ++- sql/tables/geojson.postgres.schema | 11 + sql/tables/geometries.go | 32 +- sql/tables/geometries.postgres.schema | 11 + sql/tables/names.go | 71 +++-- sql/tables/names.postgres.schema | 22 ++ sql/tables/properties.go | 31 +- sql/tables/properties.postgres.schema | 11 + sql/tables/spelunker.go | 32 +- sql/tables/spelunker.postgres.schema | 11 + sql/tables/spr.go | 108 +++++-- sql/tables/spr.postgres.schema | 43 +++ sql/tables/supersedes.go | 23 +- sql/tables/supersedes.postgres.schema | 6 + .../sfomuseum/go-database/sql/database.go | 5 + .../sfomuseum/go-database/sql/driver.go | 2 + .../sfomuseum/go-database/sql/postgres.go | 70 +++++ .../sfomuseum/go-database/sql/table.go | 2 + vendor/modules.txt | 2 +- 30 files changed, 939 insertions(+), 94 deletions(-) create mode 100755 app/sql/tables/create/create.go create mode 100755 app/sql/tables/create/flags.go create mode 100644 sql/tables/ancestors.postgres.schema create mode 100644 sql/tables/concordances.postgres.schema create mode 100644 sql/tables/geojson.postgres.schema create mode 100644 sql/tables/geometries.postgres.schema create mode 100644 sql/tables/names.postgres.schema create mode 100644 sql/tables/properties.postgres.schema create mode 100644 sql/tables/spelunker.postgres.schema create mode 100644 sql/tables/spr.postgres.schema create mode 100644 sql/tables/supersedes.postgres.schema create mode 100644 vendor/github.com/sfomuseum/go-database/sql/postgres.go diff --git a/README.md b/README.md index e4336c1..13ce71c 100644 --- a/README.md +++ b/README.md @@ -18,6 +18,10 @@ However, it does NOT load any specific `database/sql` drivers by default. This i This package simply provides common code used to index Who's On First documents regardles of the underlying database engine. +### Postgres + +* https://github.com/whosonfirst/go-whosonfirst-database-postgres + ### SQLite * https://github.com/whosonfirst/go-whosonfirst-database-sqlite @@ -25,4 +29,5 @@ This package simply provides common code used to index Who's On First documents ## See also * https://github.com/sfomuseum/go-database/ -* https://github.com/whosonfirst/go-whosonfirst-database-sqlite \ No newline at end of file +* https://github.com/whosonfirst/go-whosonfirst-database-sqlite +* https://github.com/whosonfirst/go-whosonfirst-database-postgres \ No newline at end of file diff --git a/app/sql/index/app.go b/app/sql/index/app.go index 9d20e3f..6afeaf0 100755 --- a/app/sql/index/app.go +++ b/app/sql/index/app.go @@ -81,8 +81,25 @@ func RunWithFlagSet(ctx context.Context, fs *flag.FlagSet) error { } }() - switch database_sql.Driver(db) { - case "sqlite": + db_driver := database_sql.Driver(db) + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + + if spatial_tables { + rtree = false + geometries = true + } + + if rtree { + return fmt.Errorf("-rtree table not supported by the %s driver", db_driver) + } + + if search { + return fmt.Errorf("-search table not (yet) supported by the %s driver", db_driver) + } + + case database_sql.SQLITE_DRIVER: // optimize query performance // https://www.sqlite.org/pragma.html#pragma_optimize diff --git a/app/sql/tables/create/create.go b/app/sql/tables/create/create.go new file mode 100755 index 0000000..954d1da --- /dev/null +++ b/app/sql/tables/create/create.go @@ -0,0 +1,293 @@ +package create + +import ( + "context" + "flag" + "fmt" + "log/slog" + "slices" + + database_sql "github.com/sfomuseum/go-database/sql" + "github.com/sfomuseum/go-flags/flagset" + "github.com/whosonfirst/go-whosonfirst-database/sql/tables" +) + +const index_alt_all string = "*" + +func Run(ctx context.Context) error { + fs := DefaultFlagSet() + return RunWithFlagSet(ctx, fs) +} + +// To do: Add RunWithOptions... + +func RunWithFlagSet(ctx context.Context, fs *flag.FlagSet) error { + + flagset.Parse(fs) + + if verbose { + slog.SetLogLoggerLevel(slog.LevelDebug) + slog.Debug("Verbose logging enabled") + } + + if spatial_tables { + rtree = true + geojson = true + properties = true + spr = true + } + + if spelunker_tables { + // rtree = true + spr = true + spelunker = true + geojson = true + concordances = true + ancestors = true + search = true + + to_create_alt := []string{ + tables.GEOJSON_TABLE_NAME, + } + + for _, table_name := range to_create_alt { + + if !slices.Contains(index_alt, table_name) { + index_alt = append(index_alt, table_name) + } + } + + } + + logger := slog.Default() + + db, err := database_sql.OpenWithURI(ctx, database_uri) + + if err != nil { + return err + } + + defer func() { + + err := db.Close() + + if err != nil { + logger.Error("Failed to close database connection", "error", err) + } + }() + + to_create := make([]database_sql.Table, 0) + + if geojson || all { + + geojson_opts, err := tables.DefaultGeoJSONTableOptions() + + if err != nil { + return fmt.Errorf("failed to create '%s' table options because %s", tables.GEOJSON_TABLE_NAME, err) + } + + // alt_files is deprecated (20240229/straup) + + if alt_files || slices.Contains(index_alt, tables.GEOJSON_TABLE_NAME) || slices.Contains(index_alt, index_alt_all) { + geojson_opts.IndexAltFiles = true + } + + gt, err := tables.NewGeoJSONTableWithDatabaseAndOptions(ctx, db, geojson_opts) + + if err != nil { + return fmt.Errorf("failed to create '%s' table because %s", tables.GEOJSON_TABLE_NAME, err) + } + + to_create = append(to_create, gt) + } + + if supersedes || all { + + t, err := tables.NewSupersedesTableWithDatabase(ctx, db) + + if err != nil { + return fmt.Errorf("failed to create '%s' table because %s", tables.SUPERSEDES_TABLE_NAME, err) + } + + to_create = append(to_create, t) + } + + if rtree || all { + + rtree_opts, err := tables.DefaultRTreeTableOptions() + + if err != nil { + return fmt.Errorf("failed to create 'rtree' table options because %s", err) + } + + // alt_files is deprecated (20240229/straup) + + if alt_files || slices.Contains(index_alt, tables.RTREE_TABLE_NAME) || slices.Contains(index_alt, index_alt_all) { + rtree_opts.IndexAltFiles = true + } + + gt, err := tables.NewRTreeTableWithDatabaseAndOptions(ctx, db, rtree_opts) + + if err != nil { + return fmt.Errorf("failed to create 'rtree' table because %s", err) + } + + to_create = append(to_create, gt) + } + + if properties || all { + + properties_opts, err := tables.DefaultPropertiesTableOptions() + + if err != nil { + return fmt.Errorf("failed to create 'properties' table options because %s", err) + } + + // alt_files is deprecated (20240229/straup) + + if alt_files || slices.Contains(index_alt, tables.PROPERTIES_TABLE_NAME) || slices.Contains(index_alt, index_alt_all) { + properties_opts.IndexAltFiles = true + } + + gt, err := tables.NewPropertiesTableWithDatabaseAndOptions(ctx, db, properties_opts) + + if err != nil { + return fmt.Errorf("failed to create 'properties' table because %s", err) + } + + to_create = append(to_create, gt) + } + + if spr || all { + + spr_opts, err := tables.DefaultSPRTableOptions() + + if err != nil { + return fmt.Errorf("Failed to create '%s' table options because %v", tables.SPR_TABLE_NAME, err) + } + + // alt_files is deprecated (20240229/straup) + + if alt_files || slices.Contains(index_alt, tables.SPR_TABLE_NAME) || slices.Contains(index_alt, index_alt_all) { + spr_opts.IndexAltFiles = true + } + + st, err := tables.NewSPRTableWithDatabaseAndOptions(ctx, db, spr_opts) + + if err != nil { + return fmt.Errorf("failed to create '%s' table because %s", tables.SPR_TABLE_NAME, err) + } + + to_create = append(to_create, st) + } + + if spelunker || all { + + spelunker_opts, err := tables.DefaultSpelunkerTableOptions() + + if err != nil { + return fmt.Errorf("Failed to create '%s' table options because %v", tables.SPELUNKER_TABLE_NAME, err) + } + + // alt_files is deprecated (20240229/straup) + + if alt_files || slices.Contains(index_alt, tables.SPELUNKER_TABLE_NAME) || slices.Contains(index_alt, index_alt_all) { + spelunker_opts.IndexAltFiles = true + } + + st, err := tables.NewSpelunkerTableWithDatabaseAndOptions(ctx, db, spelunker_opts) + + if err != nil { + return fmt.Errorf("failed to create '%s' table because %s", tables.SPELUNKER_TABLE_NAME, err) + } + + to_create = append(to_create, st) + } + + if names || all { + + nm, err := tables.NewNamesTableWithDatabase(ctx, db) + + if err != nil { + return fmt.Errorf("failed to create '%s' table because %s", tables.NAMES_TABLE_NAME, err) + } + + to_create = append(to_create, nm) + } + + if ancestors || all { + + an, err := tables.NewAncestorsTableWithDatabase(ctx, db) + + if err != nil { + return fmt.Errorf("failed to create '%s' table because %s", tables.ANCESTORS_TABLE_NAME, err) + } + + to_create = append(to_create, an) + } + + if concordances || all { + + cn, err := tables.NewConcordancesTableWithDatabase(ctx, db) + + if err != nil { + return fmt.Errorf("failed to create '%s' table because %s", tables.CONCORDANCES_TABLE_NAME, err) + } + + to_create = append(to_create, cn) + } + + // see the way we don't check all here - that's so people who don't have + // spatialite installed can still use all (20180122/thisisaaronland) + + if geometries { + + geometries_opts, err := tables.DefaultGeometriesTableOptions() + + if err != nil { + return fmt.Errorf("failed to create '%s' table options because %v", tables.GEOMETRIES_TABLE_NAME, err) + } + + // alt_files is deprecated (20240229/straup) + + if alt_files || slices.Contains(index_alt, tables.CONCORDANCES_TABLE_NAME) || slices.Contains(index_alt, index_alt_all) { + geometries_opts.IndexAltFiles = true + } + + gm, err := tables.NewGeometriesTableWithDatabaseAndOptions(ctx, db, geometries_opts) + + if err != nil { + return fmt.Errorf("failed to create '%s' table because %v", tables.CONCORDANCES_TABLE_NAME, err) + } + + to_create = append(to_create, gm) + } + + // see the way we don't check all here either - that's because this table can be + // brutally slow to index and should probably really just be a separate database + // anyway... (20180214/thisisaaronland) + + if search { + + // ALT FILES... + + st, err := tables.NewSearchTableWithDatabase(ctx, db) + + if err != nil { + return fmt.Errorf("failed to create 'search' table because %v", err) + } + + to_create = append(to_create, st) + } + + if len(to_create) == 0 { + return fmt.Errorf("You forgot to specify which (any) tables to index") + } + + db_opts := database_sql.DefaultConfigureDatabaseOptions() + db_opts.CreateTablesIfNecessary = true + db_opts.Tables = to_create + + return database_sql.ConfigureDatabase(ctx, db, db_opts) + +} diff --git a/app/sql/tables/create/flags.go b/app/sql/tables/create/flags.go new file mode 100755 index 0000000..8f85dbb --- /dev/null +++ b/app/sql/tables/create/flags.go @@ -0,0 +1,72 @@ +package create + +import ( + "flag" + + "github.com/sfomuseum/go-flags/flagset" + "github.com/sfomuseum/go-flags/multi" +) + +var iterator_uri string + +var database_uri string + +var all bool +var ancestors bool +var concordances bool +var geojson bool +var spelunker bool +var geometries bool +var names bool +var rtree bool +var properties bool +var search bool +var spr bool +var supersedes bool + +var spatial_tables bool +var spelunker_tables bool + +var alt_files bool +var strict_alt_files bool + +var index_alt multi.MultiString + +var index_relations bool +var relations_uri string + +var verbose bool + +func DefaultFlagSet() *flag.FlagSet { + + fs := flagset.NewFlagSet("index") + + fs.StringVar(&database_uri, "database-uri", "", "...") + + fs.BoolVar(&all, "all", false, "Index all tables (except the 'search' and 'geometries' tables which you need to specify explicitly)") + fs.BoolVar(&ancestors, "ancestors", false, "Index the 'ancestors' tables") + fs.BoolVar(&concordances, "concordances", false, "Index the 'concordances' tables") + fs.BoolVar(&geojson, "geojson", false, "Index the 'geojson' table") + fs.BoolVar(&spelunker, "spelunker", false, "Index the 'spelunker' table") + fs.BoolVar(&geometries, "geometries", false, "Index the 'geometries' table (requires that libspatialite already be installed)") + fs.BoolVar(&names, "names", false, "Index the 'names' table") + fs.BoolVar(&rtree, "rtree", false, "Index the 'rtree' table") + fs.BoolVar(&properties, "properties", false, "Index the 'properties' table") + fs.BoolVar(&search, "search", false, "Index the 'search' table (using SQLite FTS4 full-text indexer)") + fs.BoolVar(&spr, "spr", false, "Index the 'spr' table") + fs.BoolVar(&supersedes, "supersedes", false, "Index the 'supersedes' table") + + fs.BoolVar(&spatial_tables, "spatial-tables", false, "If true then index the necessary tables for use with the whosonfirst/go-whosonfirst-spatial-sqlite package.") + fs.BoolVar(&spelunker_tables, "spelunker-tables", false, "If true then index the necessary tables for use with the whosonfirst/go-whosonfirst-spelunker packages") + + fs.BoolVar(&alt_files, "index-alt-files", false, "Index alt geometries. This flag is deprecated, please use -index-alt=TABLE,TABLE,etc. instead. To index alt geometries in all the applicable tables use -index-alt=*") + fs.Var(&index_alt, "index-alt", "Zero or more table names where alt geometry files should be indexed.") + + fs.BoolVar(&strict_alt_files, "strict-alt-files", true, "Be strict when indexing alt geometries") + + fs.BoolVar(&index_relations, "index-relations", false, "Index the records related to a feature, specifically wof:belongsto, wof:depicts and wof:involves. Alt files for relations are not indexed at this time.") + fs.StringVar(&relations_uri, "index-relations-reader-uri", "", "A valid go-reader.Reader URI from which to read data for a relations candidate.") + + fs.BoolVar(&verbose, "verbose", false, "Enable verbose (debug) logging") + return fs +} diff --git a/cmd/wof-sql-index/main.go b/cmd/wof-sql-index/main.go index be60fa8..03c4099 100755 --- a/cmd/wof-sql-index/main.go +++ b/cmd/wof-sql-index/main.go @@ -5,12 +5,12 @@ package main import ( "context" "log" - + "github.com/whosonfirst/go-whosonfirst-database/app/sql/index" ) func main() { - + ctx := context.Background() err := index.Run(ctx) diff --git a/go.mod b/go.mod index 9fb849c..0fca960 100644 --- a/go.mod +++ b/go.mod @@ -4,7 +4,7 @@ go 1.23.3 require ( github.com/paulmach/orb v0.11.1 - github.com/sfomuseum/go-database v0.0.7 + github.com/sfomuseum/go-database v0.0.8 github.com/sfomuseum/go-flags v0.10.0 github.com/tidwall/gjson v1.18.0 github.com/whosonfirst/go-reader v1.0.2 diff --git a/go.sum b/go.sum index c59a063..0dc2e5d 100644 --- a/go.sum +++ b/go.sum @@ -30,8 +30,8 @@ github.com/paulmach/protoscan v0.2.1/go.mod h1:SpcSwydNLrxUGSDvXvO0P7g7AuhJ7lcKf github.com/pkg/errors v0.9.1/go.mod h1:bwawxfHBFNV+L2hUp1rHADufV3IMtnDRdf1r5NINEl0= github.com/pmezard/go-difflib v1.0.0 h1:4DBwDE0NGyQoBHbLQYPwSUPoCMWR5BEzIk/f1lZbAQM= github.com/pmezard/go-difflib v1.0.0/go.mod h1:iKH77koFhYxTK1pcRnkKkqfTogsbg7gZNVY4sRDYZ/4= -github.com/sfomuseum/go-database v0.0.7 h1:+eeWhkMMLQ32hNdXCJiINsWS7EEhqmrTFPNEH93lwTg= -github.com/sfomuseum/go-database v0.0.7/go.mod h1:c1oZwb0M0aYSI48SgE8b5iIrGrLFA8eJFk46E5g4JOM= +github.com/sfomuseum/go-database v0.0.8 h1:dVRZg09bXAtu3c+OAYX/ne85zli2W/0hb6N9G02fHyA= +github.com/sfomuseum/go-database v0.0.8/go.mod h1:c1oZwb0M0aYSI48SgE8b5iIrGrLFA8eJFk46E5g4JOM= github.com/sfomuseum/go-edtf v1.1.1 h1:R5gElndHGDaK/rGSh2X+ulaLtlcHCdQA1cTzB8e9wv8= github.com/sfomuseum/go-edtf v1.1.1/go.mod h1:1rP0EJZ/84j3HO80vGcnG2T9MFBDAFyTNtjrr8cv3T4= github.com/sfomuseum/go-flags v0.10.0 h1:1OC1ACxpWMsl3XQ9OeNVMQj7Zi2CzufP3Rym3mPI8HU= diff --git a/sql/tables/ancestors.go b/sql/tables/ancestors.go index 363bc02..ff44acd 100644 --- a/sql/tables/ancestors.go +++ b/sql/tables/ancestors.go @@ -81,15 +81,24 @@ func (t *AncestorsTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte) return MissingPropertyError(t, "id", err) } + db_driver := database_sql.Driver(db) + tx, err := db.Begin() if err != nil { return database_sql.BeginTransactionError(t, err) } - sql := fmt.Sprintf(`DELETE FROM %s WHERE id = ?`, t.Name()) + var delete_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + delete_q = fmt.Sprintf(`DELETE FROM %s WHERE id = $1`, t.Name()) + default: + delete_q = fmt.Sprintf(`DELETE FROM %s WHERE id = ?`, t.Name()) + } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(delete_q) if err != nil { return database_sql.PrepareStatementError(t, err) @@ -112,13 +121,29 @@ func (t *AncestorsTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte) ancestor_placetype := strings.Replace(pt_key, "_id", "", -1) - sql := fmt.Sprintf(`INSERT OR REPLACE INTO %s ( - id, ancestor_id, ancestor_placetype, lastmodified - ) VALUES ( - ?, ?, ?, ? - )`, t.Name()) + var q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + + q = fmt.Sprintf(`INSERT INTO %s ( + id, ancestor_id, ancestor_placetype, lastmodified + ) VALUES ( + $1, $2, $3, $4 + ) ON CONFLICT(id, ancestor_id) DO UPDATE SET + ancestor_placetype = EXCLUDED.ancestor_placetype, + lastmodified = EXCLUDED.lastmodified`, t.Name()) + + default: + + q = fmt.Sprintf(`INSERT OR REPLACE INTO %s ( + id, ancestor_id, ancestor_placetype, lastmodified + ) VALUES ( + ?, ?, ?, ? + )`, t.Name()) + } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(q) if err != nil { return database_sql.PrepareStatementError(t, err) diff --git a/sql/tables/ancestors.postgres.schema b/sql/tables/ancestors.postgres.schema new file mode 100644 index 0000000..102d037 --- /dev/null +++ b/sql/tables/ancestors.postgres.schema @@ -0,0 +1,8 @@ +CREATE TABLE {{ .Name }} ( + id BIGINT NOT NULL, + ancestor_id BIGINT NOT NULL, + ancestor_placetype TEXT, + lastmodified BIGINT +); + +CREATE UNIQUE INDEX {{ .Name }}_by_ancestor ON {{ .Name }} (id, ancestor_id); \ No newline at end of file diff --git a/sql/tables/concordances.go b/sql/tables/concordances.go index 5ff7e3c..b292456 100644 --- a/sql/tables/concordances.go +++ b/sql/tables/concordances.go @@ -73,6 +73,8 @@ func (t *ConcordancesTable) IndexFeature(ctx context.Context, db *sql.DB, f []by return nil } + db_driver := database_sql.Driver(db) + id, err := properties.Id(f) if err != nil { @@ -85,9 +87,16 @@ func (t *ConcordancesTable) IndexFeature(ctx context.Context, db *sql.DB, f []by return database_sql.BeginTransactionError(t, err) } - sql := fmt.Sprintf(`DELETE FROM %s WHERE id = ?`, t.Name()) + var delete_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + delete_q = fmt.Sprintf(`DELETE FROM %s WHERE id = $1`, t.Name()) + default: + delete_q = fmt.Sprintf(`DELETE FROM %s WHERE id = ?`, t.Name()) + } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(delete_q) if err != nil { return database_sql.PrepareStatementError(t, err) @@ -106,13 +115,29 @@ func (t *ConcordancesTable) IndexFeature(ctx context.Context, db *sql.DB, f []by for other_source, other_id := range concordances { - sql := fmt.Sprintf(`INSERT OR REPLACE INTO %s ( + var insert_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + + insert_q = fmt.Sprintf(`INSERT INTO %s ( + id, other_id, other_source, lastmodified + ) VALUES ( + $1, $2, $3, $4 + ) ON CONFLICT(id, other_source) DO UPDATE SET + other_id = EXCLUDED.other_id, + lastmodified = EXCLUDED.lastmodified`, t.Name()) + + default: + + insert_q = fmt.Sprintf(`INSERT OR REPLACE INTO %s ( id, other_id, other_source, lastmodified ) VALUES ( ?, ?, ?, ? )`, t.Name()) + } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(insert_q) if err != nil { return database_sql.PrepareStatementError(t, err) diff --git a/sql/tables/concordances.postgres.schema b/sql/tables/concordances.postgres.schema new file mode 100644 index 0000000..4dc08fa --- /dev/null +++ b/sql/tables/concordances.postgres.schema @@ -0,0 +1,9 @@ +CREATE TABLE {{ .Name }} ( + id BIGINT NOT NULL, + other_id TEXT NOT NULL, + other_source TEXT, + lastmodified BIGINT +); + +CREATE UNIQUE INDEX {{ .Name }}_by_other ON {{ .Name }} (id, other_source); +CREATE INDEX {{ .Name }}_other_id ON {{ .Name }} (other_source, other_id); diff --git a/sql/tables/geojson.go b/sql/tables/geojson.go index 60c8996..2c689d5 100644 --- a/sql/tables/geojson.go +++ b/sql/tables/geojson.go @@ -145,13 +145,43 @@ func (t *GeoJSONTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte) e return database_sql.BeginTransactionError(t, err) } - sql := fmt.Sprintf(`INSERT OR REPLACE INTO %s ( - id, body, source, is_alt, alt_label, lastmodified - ) VALUES ( - ?, ?, ?, ?, ?, ? - )`, t.Name()) + str_body := string(f) + + var q string + + args := []any{ + id, + str_body, + source, + is_alt, + alt_label, + lastmod, + } + + switch database_sql.Driver(db) { + case database_sql.POSTGRES_DRIVER: + + q = fmt.Sprintf(`INSERT INTO %s ( + id, body, source, is_alt, alt_label, lastmodified + ) VALUES ( + $1, $2, $3, $4, $5, $6 + ) ON CONFLICT (id, alt_label) DO UPDATE SET + body = EXCLUDED.body, + source = EXCLUDED.source, + is_alt = EXCLUDED.is_alt, + lastmodified = EXCLUDED.lastmodified`, t.Name()) - stmt, err := tx.Prepare(sql) + default: + + q = fmt.Sprintf(`INSERT OR REPLACE INTO %s ( + id, body, source, is_alt, alt_label, lastmodified + ) VALUES ( + ?, ?, ?, ?, ?, ? + )`, t.Name()) + + } + + stmt, err := tx.Prepare(q) if err != nil { return database_sql.PrepareStatementError(t, err) @@ -159,9 +189,7 @@ func (t *GeoJSONTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte) e defer stmt.Close() - str_body := string(f) - - _, err = stmt.Exec(id, str_body, source, is_alt, alt_label, lastmod) + _, err = stmt.Exec(args...) if err != nil { return database_sql.ExecuteStatementError(t, err) diff --git a/sql/tables/geojson.postgres.schema b/sql/tables/geojson.postgres.schema new file mode 100644 index 0000000..ac392fe --- /dev/null +++ b/sql/tables/geojson.postgres.schema @@ -0,0 +1,11 @@ +CREATE TABLE {{ .Name }} ( + id BIGINT NOT NULL, + body TEXT, + source TEXT, + is_alt BOOLEAN, + alt_label TEXT, + lastmodified BIGINT +); + +CREATE UNIQUE INDEX {{ .Name }}_id_alt ON {{ .Name }} (id, alt_label); +CREATE INDEX {{ .Name }}_by_source ON {{ .Name }} (source); diff --git a/sql/tables/geometries.go b/sql/tables/geometries.go index d81b443..eb9440d 100644 --- a/sql/tables/geometries.go +++ b/sql/tables/geometries.go @@ -139,6 +139,8 @@ func (t *GeometriesTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte lastmod := properties.LastModified(f) + db_driver := database_sql.Driver(db) + tx, err := db.Begin() if err != nil { @@ -155,13 +157,31 @@ func (t *GeometriesTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte str_wkt := wkt.MarshalString(orb_geom) - sql := fmt.Sprintf(`INSERT OR REPLACE INTO %s ( - id, is_alt, alt_label, type, geom, lastmodified - ) VALUES ( - ?, ?, ?, ?, GeomFromText('%s', 4326), ? - )`, t.Name(), str_wkt) + var insert_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + + insert_q = fmt.Sprintf(`INSERT INTO %s ( + id, is_alt, alt_label, type, geometry, lastmodified + ) VALUES ( + $1, $2, $3, $4, ST_GeomFromText('%s', 4326), $5 + ) ON CONFLICT(id, alt_label) DO UPDATE SET + is_alt = EXCLUDED.is_alt, + type = EXCLUDED.type, + geometry = EXCLUDED.geometry, + lastmodified = EXCLUDED.lastmodified`, t.Name(), str_wkt) + + default: + + insert_q = fmt.Sprintf(`INSERT OR REPLACE INTO %s ( + id, is_alt, alt_label, type, geom, lastmodified + ) VALUES ( + ?, ?, ?, ?, GeomFromText('%s', 4326), ? + )`, t.Name(), str_wkt) + } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(insert_q) if err != nil { return database_sql.PrepareStatementError(t, err) diff --git a/sql/tables/geometries.postgres.schema b/sql/tables/geometries.postgres.schema new file mode 100644 index 0000000..ad0f3d9 --- /dev/null +++ b/sql/tables/geometries.postgres.schema @@ -0,0 +1,11 @@ +CREATE TABLE {{ .Name }} ( + id BIGINT NOT NULL, + geometry GEOGRAPHY(GEOMETRY, 4326), + type TEXT, + is_alt BOOLEAN, + alt_label TEXT, + lastmodified BIGINT +); + +CREATE UNIQUE INDEX {{ .Name }}_by_id ON {{ .Name }} (id, alt_label); +CREATE INDEX {{ .Name }}_geometries_by_lastmod ON {{ .Name }} (lastmodified); diff --git a/sql/tables/names.go b/sql/tables/names.go index be3375a..f7cafa8 100644 --- a/sql/tables/names.go +++ b/sql/tables/names.go @@ -100,15 +100,24 @@ func (t *NamesTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte) err lastmod := properties.LastModified(f) names := properties.Names(f) + db_driver := database_sql.Driver(db) + tx, err := db.Begin() if err != nil { return database_sql.BeginTransactionError(t, err) } - sql := fmt.Sprintf(`DELETE FROM %s WHERE id = ?`, t.Name()) + var delete_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + delete_q = fmt.Sprintf(`DELETE FROM %s WHERE id = $1`, t.Name()) + default: + delete_q = fmt.Sprintf(`DELETE FROM %s WHERE id = ?`, t.Name()) + } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(delete_q) if err != nil { return database_sql.PrepareStatementError(t, err) @@ -132,23 +141,47 @@ func (t *NamesTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte) err for _, n := range names { - sql := fmt.Sprintf(`INSERT INTO %s ( - id, placetype, country, - language, extlang, - region, script, variant, - extension, privateuse, - name, - lastmodified - ) VALUES ( - ?, ?, ?, - ?, ?, - ?, ?, ?, - ?, ?, - ?, - ? - )`, t.Name()) - - stmt, err := tx.Prepare(sql) + var insert_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + + insert_q = fmt.Sprintf(`INSERT INTO %s ( + id, placetype, country, + language, extlang, + region, script, variant, + extension, privateuse, + name, + lastmodified + ) VALUES ( + $1, $2, $3, + $4, $5, + $6, $7, $8, + $9, $10, + $11, + $12 + )`, t.Name()) + + default: + + insert_q = fmt.Sprintf(`INSERT INTO %s ( + id, placetype, country, + language, extlang, + region, script, variant, + extension, privateuse, + name, + lastmodified + ) VALUES ( + ?, ?, ?, + ?, ?, + ?, ?, ?, + ?, ?, + ?, + ? + )`, t.Name()) + } + + stmt, err := tx.Prepare(insert_q) if err != nil { return database_sql.PrepareStatementError(t, err) diff --git a/sql/tables/names.postgres.schema b/sql/tables/names.postgres.schema new file mode 100644 index 0000000..d29377c --- /dev/null +++ b/sql/tables/names.postgres.schema @@ -0,0 +1,22 @@ +CREATE TABLE {{ .Name }} ( + id BIGINT NOT NULL, + placetype TEXT, + country TEXT, + language TEXT, + extlang TEXT, + script TEXT, + region TEXT, + variant TEXT, + extension TEXT, + privateuse TEXT, + name TEXT, + lastmodified BIGINT +); + +CREATE INDEX {{ .Name }}_by_lastmod ON {{ .Name }} (lastmodified); +CREATE INDEX {{ .Name }}_by_country ON {{ .Name }} (country,privateuse,placetype); +CREATE INDEX {{ .Name }}_by_language ON {{ .Name }} (language,privateuse,placetype); +CREATE INDEX {{ .Name }}_by_placetype ON {{ .Name }} (placetype,country,privateuse); +CREATE INDEX {{ .Name }}_by_name ON {{ .Name }} (name, placetype, country); +CREATE INDEX {{ .Name }}_by_name_private ON {{ .Name }} (name, privateuse, placetype, country); +CREATE INDEX {{ .Name }}_by_wofid ON {{ .Name }} (id); diff --git a/sql/tables/properties.go b/sql/tables/properties.go index 4fcceec..08043eb 100644 --- a/sql/tables/properties.go +++ b/sql/tables/properties.go @@ -127,19 +127,38 @@ func (t *PropertiesTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte lastmod := properties.LastModified(f) + db_driver := database_sql.Driver(db) + tx, err := db.Begin() if err != nil { return database_sql.BeginTransactionError(t, err) } - sql := fmt.Sprintf(`INSERT OR REPLACE INTO %s ( - id, body, is_alt, alt_label, lastmodified - ) VALUES ( - ?, ?, ?, ?, ? - )`, t.Name()) + var insert_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + + insert_q = fmt.Sprintf(`INSERT INTO %s ( + id, body, is_alt, alt_label, lastmodified + ) VALUES ( + $1, $2, $3, $4, $5 + ) ON CONFLICT(id, alt_label) DO UPDATE SET + body = EXCLUDED.body, + is_alt = EXCLUDED.is_alt, + lastmodified = EXCLUDED.lastmodified`, t.Name()) + + default: + + insert_q = fmt.Sprintf(`INSERT OR REPLACE INTO %s ( + id, body, is_alt, alt_label, lastmodified + ) VALUES ( + ?, ?, ?, ?, ? + )`, t.Name()) + } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(insert_q) if err != nil { return database_sql.PrepareStatementError(t, err) diff --git a/sql/tables/properties.postgres.schema b/sql/tables/properties.postgres.schema new file mode 100644 index 0000000..56c7c9d --- /dev/null +++ b/sql/tables/properties.postgres.schema @@ -0,0 +1,11 @@ +CREATE TABLE {{ .Name }} ( + id BIGINT NOT NULL, + body TEXT, + is_alt BOOLEAN, + alt_label TEXT, + lastmodified BIGINT +); + +CREATE UNIQUE INDEX {{ .Name }}_by_id ON {{ .Name }} (id, alt_label); +CREATE INDEX {{ .Name }}_by_alt ON {{ .Name }} (id, is_alt, alt_label); +CREATE INDEX {{ .Name }}_by_lastmod ON {{ .Name }} (lastmodified); diff --git a/sql/tables/spelunker.go b/sql/tables/spelunker.go index cd67e0a..90e7506 100644 --- a/sql/tables/spelunker.go +++ b/sql/tables/spelunker.go @@ -139,19 +139,39 @@ func (t *SpelunkerTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte) return fmt.Errorf("Failed to prepare spelunker document, %w", err) } + db_driver := database_sql.Driver(db) + tx, err := db.Begin() if err != nil { return database_sql.BeginTransactionError(t, err) } - sql := fmt.Sprintf(`INSERT OR REPLACE INTO %s ( - id, body, source, is_alt, alt_label, lastmodified - ) VALUES ( - ?, ?, ?, ?, ?, ? - )`, t.Name()) + var insert_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + + insert_q = fmt.Sprintf(`INSERT INTO %s ( + id, body, source, is_alt, alt_label, lastmodified + ) VALUES ( + $1, $2, $3, $4, $5, $6 + ) ON CONFLICT (id, alt_label) DO UPDATE SET + body = EXCLUDED.body, + source = EXCLUDED.source, + is_alt = EXCLUDED.is_alt, + lastmodified = EXCLUDED.lastmodified`, t.Name()) + + default: + + insert_q = fmt.Sprintf(`INSERT OR REPLACE INTO %s ( + id, body, source, is_alt, alt_label, lastmodified + ) VALUES ( + ?, ?, ?, ?, ?, ? + )`, t.Name()) + } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(insert_q) if err != nil { return database_sql.PrepareStatementError(t, err) diff --git a/sql/tables/spelunker.postgres.schema b/sql/tables/spelunker.postgres.schema new file mode 100644 index 0000000..2ac7a7b --- /dev/null +++ b/sql/tables/spelunker.postgres.schema @@ -0,0 +1,11 @@ +CREATE TABLE {{ .Name }} ( + id BIGINT NOT NULL, + body JSON, + source TEXT, + is_alt BOOLEAN, + alt_label TEXT, + lastmodified BIGINT +); + +CREATE UNIQUE INDEX {{ .Name }}_id_alt ON {{ .Name }} (id, alt_label); +CREATE INDEX {{ .Name }}_by_source ON {{ .Name }} (source); diff --git a/sql/tables/spr.go b/sql/tables/spr.go index c8fb516..d0860d5 100644 --- a/sql/tables/spr.go +++ b/sql/tables/spr.go @@ -141,31 +141,89 @@ func (t *SPRTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte) error } - sql := fmt.Sprintf(`INSERT OR REPLACE INTO %s ( - id, parent_id, name, placetype, - inception, cessation, - country, repo, - latitude, longitude, - min_latitude, min_longitude, - max_latitude, max_longitude, - is_current, is_deprecated, is_ceased, - is_superseded, is_superseding, - superseded_by, supersedes, belongsto, - is_alt, alt_label, - lastmodified + db_driver := database_sql.Driver(db) + + var insert_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + + insert_q = fmt.Sprintf(`INSERT INTO %s ( + id, parent_id, name, placetype, + inception, cessation, + country, repo, + latitude, longitude, + min_latitude, min_longitude, + max_latitude, max_longitude, + is_current, is_deprecated, is_ceased, + is_superseded, is_superseding, + superseded_by, supersedes, belongsto, + is_alt, alt_label, + lastmodified ) VALUES ( - ?, ?, ?, ?, - ?, ?, - ?, ?, - ?, ?, - ?, ?, - ?, ?, - ?, ?, ?, - ?, ?, ?, - ?, ?, - ?, ?, - ? - )`, t.Name()) // ON CONFLICT DO BLAH BLAH BLAH + $1, $2, $3, $4, + $5, $6, + $7, $8, + $9, $10, + $11, $12, + $13, $14, + $15, $16, $17, + $18, $19, $20, + $21, $22, + $23, $24, + $25 + ) ON CONFLICT(id, alt_label) DO UPDATE SET + parent_id=EXCLUDED.parent_id, + name=EXCLUDED.name, + placetype=EXCLUDED.placetype, + inception=EXCLUDED.inception, + cessation=EXCLUDED.cessation, + country=EXCLUDED.country, + repo=EXCLUDED.repo, + latitude=EXCLUDED.latitude, + longitude=EXCLUDED.longitude, + min_latitude=EXCLUDED.min_latitude, + min_longitude=EXCLUDED.min_longitude, + max_latitude=EXCLUDED.max_latitude, + max_longitude=EXCLUDED.max_longitude, + is_current=EXCLUDED.is_current, + is_deprecated=EXCLUDED.is_deprecated, + is_ceased=EXCLUDED.is_ceased, + is_superseded=EXCLUDED.is_superseded, + is_superseding=EXCLUDED.is_superseding, + superseded_by=EXCLUDED.superseded_by, + supersedes=EXCLUDED.supersedes, + belongsto=EXCLUDED.belongsto, + is_alt=EXCLUDED.is_alt`, t.Name()) + + default: + + insert_q = fmt.Sprintf(`INSERT OR REPLACE INTO %s ( + id, parent_id, name, placetype, + inception, cessation, + country, repo, + latitude, longitude, + min_latitude, min_longitude, + max_latitude, max_longitude, + is_current, is_deprecated, is_ceased, + is_superseded, is_superseding, + superseded_by, supersedes, belongsto, + is_alt, alt_label, + lastmodified + ) VALUES ( + ?, ?, ?, ?, + ?, ?, + ?, ?, + ?, ?, + ?, ?, + ?, ?, + ?, ?, ?, + ?, ?, ?, + ?, ?, + ?, ?, + ? + )`, t.Name()) + } superseded_by := int64ToString(s.SupersededBy()) supersedes := int64ToString(s.Supersedes()) @@ -205,7 +263,7 @@ func (t *SPRTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte) error return database_sql.BeginTransactionError(t, err) } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(insert_q) if err != nil { return database_sql.PrepareStatementError(t, err) diff --git a/sql/tables/spr.postgres.schema b/sql/tables/spr.postgres.schema new file mode 100644 index 0000000..209192d --- /dev/null +++ b/sql/tables/spr.postgres.schema @@ -0,0 +1,43 @@ +CREATE TABLE {{ .Name }} ( + id TEXT NOT NULL, + parent_id BIGINT, + name TEXT, + placetype TEXT, + inception TEXT, + cessation TEXT, + country TEXT, + repo TEXT, + latitude REAL, + longitude REAL, + min_latitude REAL, + min_longitude REAL, + max_latitude REAL, + max_longitude REAL, + is_current BIGINT, + is_deprecated BIGINT, + is_ceased BIGINT, + is_superseded BIGINT, + is_superseding BIGINT, + superseded_by TEXT, + supersedes TEXT, + belongsto TEXT, + is_alt BOOLEAN, + alt_label TEXT, + lastmodified BIGINT +); + +CREATE UNIQUE INDEX {{ .Name }}_by_id ON {{ .Name }} (id, alt_label); +CREATE INDEX {{ .Name }}_by_lastmod ON {{ .Name }} (lastmodified); +CREATE INDEX {{ .Name }}_by_parent ON {{ .Name }} (parent_id, is_current, lastmodified); +CREATE INDEX {{ .Name }}_by_placetype ON {{ .Name }} (placetype, is_current, lastmodified); +CREATE INDEX {{ .Name }}_by_country ON {{ .Name }} (country, placetype, is_current, lastmodified); +CREATE INDEX {{ .Name }}_by_name ON {{ .Name }} (name, placetype, is_current, lastmodified); +CREATE INDEX {{ .Name }}_by_centroid ON {{ .Name }} (latitude, longitude, is_current, lastmodified); +CREATE INDEX {{ .Name }}_by_bbox ON {{ .Name }} (min_latitude, min_longitude, max_latitude, max_longitude, placetype, is_current, lastmodified); +CREATE INDEX {{ .Name }}_by_repo ON {{ .Name }} (repo, lastmodified); +CREATE INDEX {{ .Name }}_by_current ON {{ .Name }} (is_current, lastmodified); +CREATE INDEX {{ .Name }}_by_deprecated ON {{ .Name }} (is_deprecated, lastmodified); +CREATE INDEX {{ .Name }}_by_ceased ON {{ .Name }} (is_ceased, lastmodified); +CREATE INDEX {{ .Name }}_by_superseded ON {{ .Name }} (is_superseded, lastmodified); +CREATE INDEX {{ .Name }}_by_superseding ON {{ .Name }} (is_superseding, lastmodified); +CREATE INDEX {{ .Name }}_obsolete ON {{ .Name }} (is_deprecated, is_superseded); diff --git a/sql/tables/supersedes.go b/sql/tables/supersedes.go index 0bd4588..be5b0fb 100644 --- a/sql/tables/supersedes.go +++ b/sql/tables/supersedes.go @@ -74,19 +74,38 @@ func (t *SupersedesTable) IndexFeature(ctx context.Context, db *sql.DB, f []byte lastmod := properties.LastModified(f) + db_driver := database_sql.Driver(db) + tx, err := db.Begin() if err != nil { return database_sql.BeginTransactionError(t, err) } - sql := fmt.Sprintf(`INSERT OR REPLACE INTO %s ( + var insert_q string + + switch db_driver { + case database_sql.POSTGRES_DRIVER: + + insert_q = fmt.Sprintf(`INSERT INTO %s ( + id, superseded_id, superseded_by_id, lastmodified + ) VALUES ( + $1, $2, $3, $4 + ) ON CONFLICT(id) DO UPDATE SET + superseded_id = EXCLUDED.superseded_id, + superseded_by_id = EXCLUDED.superseded_by_id, + lastmodified = EXCLUDED.lastmodified`, t.Name()) + + default: + + insert_q = fmt.Sprintf(`INSERT OR REPLACE INTO %s ( id, superseded_id, superseded_by_id, lastmodified ) VALUES ( ?, ?, ?, ? )`, t.Name()) + } - stmt, err := tx.Prepare(sql) + stmt, err := tx.Prepare(insert_q) if err != nil { return database_sql.PrepareStatementError(t, err) diff --git a/sql/tables/supersedes.postgres.schema b/sql/tables/supersedes.postgres.schema new file mode 100644 index 0000000..43ae115 --- /dev/null +++ b/sql/tables/supersedes.postgres.schema @@ -0,0 +1,6 @@ +CREATE TABLE {{ .Name }} ( + id BIGINT NOT NULL PRIMARY KEY, + superseded_id BIGINT NOT NULL, + superseded_by_id BIGINT NOT NULL, + lastmodified BIGINT +); diff --git a/vendor/github.com/sfomuseum/go-database/sql/database.go b/vendor/github.com/sfomuseum/go-database/sql/database.go index f23a5b6..323edef 100644 --- a/vendor/github.com/sfomuseum/go-database/sql/database.go +++ b/vendor/github.com/sfomuseum/go-database/sql/database.go @@ -5,6 +5,7 @@ import ( "database/sql" "fmt" "net/url" + "log/slog" ) type ConfigureDatabaseOptions struct { @@ -23,6 +24,8 @@ func ConfigureDatabase(ctx context.Context, db *sql.DB, opts *ConfigureDatabaseO switch Driver(db) { case SQLITE_DRIVER: return ConfigureSQLiteDatabase(ctx, db, opts) + case POSTGRES_DRIVER: + return ConfigurePostgresDatabase(ctx, db, opts) default: return fmt.Errorf("Unhandled or unsupported database driver %s", DriverTypeOf(db)) } @@ -41,6 +44,8 @@ func OpenWithURI(ctx context.Context, db_uri string) (*sql.DB, error) { engine := u.Host dsn := q.Get("dsn") + slog.Info("Create database connection", "engine", engine, "dsn", dsn) + db, err := sql.Open(engine, dsn) if err != nil { diff --git a/vendor/github.com/sfomuseum/go-database/sql/driver.go b/vendor/github.com/sfomuseum/go-database/sql/driver.go index 2b389af..48a4573 100644 --- a/vendor/github.com/sfomuseum/go-database/sql/driver.go +++ b/vendor/github.com/sfomuseum/go-database/sql/driver.go @@ -25,6 +25,8 @@ func Driver(db *sql.DB) string { switch driver_type { case "*sqlite3.SQLiteDriver", "*sqlite.Driver": return SQLITE_DRIVER + case "*pq.Driver": + return POSTGRES_DRIVER default: slog.Warn("Unhandled driver type", "type", driver_type) return "" diff --git a/vendor/github.com/sfomuseum/go-database/sql/postgres.go b/vendor/github.com/sfomuseum/go-database/sql/postgres.go new file mode 100644 index 0000000..39a8def --- /dev/null +++ b/vendor/github.com/sfomuseum/go-database/sql/postgres.go @@ -0,0 +1,70 @@ +package sql + +import ( + "context" + "database/sql" + "fmt" + "log/slog" +) + +func ConfigurePostgresDatabase(ctx context.Context, db *sql.DB, opts *ConfigureDatabaseOptions) error { + + if opts.CreateTablesIfNecessary { + + for _, t := range opts.Tables { + + logger := slog.Default() + logger = logger.With("table", t.Name()) + + exists, err := HasPostgresTable(ctx, db, t.Name()) + + if err != nil { + return fmt.Errorf("Failed to determine if table %s exists, %w", t.Name(), err) + } + + if exists { + logger.Debug("Table already exists") + continue + } + + schema, err := t.Schema(db) + + if err != nil { + return fmt.Errorf("Failed to derive schema for table %s, %w", t.Name(), err) + } + + _, err = db.ExecContext(ctx, schema) + + if err != nil { + return fmt.Errorf("Failed to create %s table, %w", t.Name(), err) + } + + logger.Debug("Created table") + } + } + + return nil +} + +// https://stackoverflow.com/questions/20582500/how-to-check-if-a-table-exists-in-a-given-schema + +func HasPostgresTable(ctx context.Context, db *sql.DB, table_name string) (bool, error) { + + logger := slog.Default() + logger = logger.With("table", table_name) + + q := "SELECT EXISTS(SELECT * FROM pg_tables WHERE schemaname='public' AND tablename=$1)" + + row := db.QueryRowContext(ctx, q, table_name) + + var exists bool + + err := row.Scan(&exists) + + if err != nil { + return false, fmt.Errorf("Failed to query table, %w", err) + } + + logger.Debug("Does table exist", "exists", exists) + return exists, nil +} diff --git a/vendor/github.com/sfomuseum/go-database/sql/table.go b/vendor/github.com/sfomuseum/go-database/sql/table.go index 5afa475..7f9252b 100644 --- a/vendor/github.com/sfomuseum/go-database/sql/table.go +++ b/vendor/github.com/sfomuseum/go-database/sql/table.go @@ -29,6 +29,8 @@ func HasTable(ctx context.Context, db *sql.DB, table_name string) (bool, error) switch Driver(db) { case SQLITE_DRIVER: return HasSQLiteTable(ctx, db, table_name) + case POSTGRES_DRIVER: + return HasPostgresTable(ctx, db, table_name) default: return false, fmt.Errorf("Unhandled or unsupported database driver %s", DriverTypeOf(db)) } diff --git a/vendor/modules.txt b/vendor/modules.txt index 43afc99..3b48b11 100644 --- a/vendor/modules.txt +++ b/vendor/modules.txt @@ -19,7 +19,7 @@ github.com/hashicorp/go-multierror github.com/paulmach/orb github.com/paulmach/orb/encoding/wkt github.com/paulmach/orb/geojson -# github.com/sfomuseum/go-database v0.0.7 +# github.com/sfomuseum/go-database v0.0.8 ## explicit; go 1.23.3 github.com/sfomuseum/go-database/sql # github.com/sfomuseum/go-edtf v1.1.1