Skip to content

Commit

Permalink
Spanner Postgres interface support (#555)
Browse files Browse the repository at this point in the history
Adds support for the [GCP Spanner Postgres
Interface](https://cloud.google.com/spanner/docs/postgresql-interface),
which only requires a slight modification to the postgres driver.

This will not work with a GoogleSQL-flavored Spanner database; support
for that will require a dedicated driver.

The new functionality is accessed with a custom `spanner-postgres://`
scheme. This is rather un-standard and something I just made up, so the
exact scheme is open for debate. We shouldn't use just `spanner://`,
since that may cause confusion down the line when a driver for Spanner
with the GoogleSQL dialect is added.

Related discussion: #369
  • Loading branch information
grahamhoyes authored Jul 9, 2024
1 parent 95b49f1 commit 95461d6
Show file tree
Hide file tree
Showing 4 changed files with 84 additions and 6 deletions.
26 changes: 26 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -312,6 +312,32 @@ bigquery://host:port/projectid/location/dataset?disable_auth=true

`disable_auth` (optional) - Pass `true` to skip Authentication, use only for testing and connecting to emulator.

#### Spanner (PostgreSQL Interface)

Spanner support is currently limited to databases using the [PostgreSQL Dialect](https://cloud.google.com/spanner/docs/postgresql-interface), which must be chosen during database creation. For future Spanner with GoogleSQL support, see [this discussion](https://github.com/amacneil/dbmate/discussions/369).

Spanner with the Postgres interface requires that the [PGAdapter](https://cloud.google.com/spanner/docs/pgadapter) is running. Use the following format for `DATABASE_URL`, with the host and port set to where the PGAdapter is running:

```shell
DATABASE_URL="spanner-postgres://127.0.0.1:5432/database_name?sslmode=disable"
```

Note that specifying a username and password is not necessary, as authentication is handled by the PGAdapter (they will be ignored by the PGAdapter if specified).

Other options of the [postgres driver](#postgresql) are supported.

Spanner also doesn't allow DDL to be executed inside explicit transactions. You must therefore specify `transaction:false` on migrations that include DDL:

```sql
-- migrate:up transaction:false
CREATE TABLE ...

-- migrate:down transaction:false
DROP TABLE ...
```

Schema dumps are not currently supported, as `pg_dump` uses functions that are not provided by Spanner.

### Creating Migrations

To create a new migration, run `dbmate new create_users_table`. You can name the migration anything you like. This will create a file `db/migrations/20151127184807_create_users_table.sql` in the current directory:
Expand Down
5 changes: 5 additions & 0 deletions docker-compose.yml
Original file line number Diff line number Diff line change
Expand Up @@ -13,13 +13,15 @@ services:
- clickhouse-cluster-01
- clickhouse-cluster-02
- bigquery
- spanner-emulator
environment:
CLICKHOUSE_TEST_URL: clickhouse://clickhouse:9000/dbmate_test
CLICKHOUSE_CLUSTER_01_TEST_URL: clickhouse://ch-cluster-01:9000/dbmate_test
CLICKHOUSE_CLUSTER_02_TEST_URL: clickhouse://ch-cluster-02:9000/dbmate_test
MYSQL_TEST_URL: mysql://root:root@mysql/dbmate_test
POSTGRES_TEST_URL: postgres://postgres:postgres@postgres/dbmate_test?sslmode=disable
BIGQUERY_TEST_URL: bigquery://test/us-east5/dbmate_test?disable_auth=true&endpoint=http%3A%2F%2Fbigquery%3A9050
SPANNER_POSTGRES_TEST_URL: spanner-postgres://spanner-emulator/dbmate_test?sslmode=disable

dbmate:
build:
Expand Down Expand Up @@ -69,3 +71,6 @@ services:
image: ghcr.io/goccy/bigquery-emulator:0.4.4
command: |
--project=test --dataset=dbmate_test
spanner-emulator:
image: gcr.io/cloud-spanner-pg-adapter/pgadapter-emulator
12 changes: 6 additions & 6 deletions pkg/driver/postgres/postgres.go
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,7 @@ func init() {
dbmate.RegisterDriver(NewDriver, "postgres")
dbmate.RegisterDriver(NewDriver, "postgresql")
dbmate.RegisterDriver(NewDriver, "redshift")
dbmate.RegisterDriver(NewDriver, "spanner-postgres")
}

// Driver provides top level database functions
Expand Down Expand Up @@ -73,17 +74,16 @@ func connectionString(u *url.URL) string {
}
if port == "" {
switch u.Scheme {
case "postgresql":
fallthrough
case "postgres":
port = "5432"
case "redshift":
port = "5439"
default:
port = "5432"
}
}

// generate output URL
out, _ := url.Parse(u.String())
// force scheme back to postgres if there was another postgres-compatible scheme
out.Scheme = "postgres"
out.Host = fmt.Sprintf("%s:%s", hostname, port)
out.RawQuery = query.Encode()
Expand Down Expand Up @@ -439,8 +439,8 @@ func (drv *Driver) quotedMigrationsTableNameParts(db dbutil.Transaction) (string
return "", "", err
}

// Quote identifiers for Redshift
if drv.databaseURL.Scheme == "redshift" {
// Quote identifiers for Redshift and Spanner
if drv.databaseURL.Scheme == "redshift" || drv.databaseURL.Scheme == "spanner-postgres" {
return pq.QuoteIdentifier(schema), pq.QuoteIdentifier(strings.Join(tableNameParts, ".")), nil
}

Expand Down
47 changes: 47 additions & 0 deletions pkg/driver/postgres/postgres_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -30,6 +30,15 @@ func testRedshiftDriver(t *testing.T) *Driver {
return drv.(*Driver)
}

func testSpannerPostgresDriver(t *testing.T) *Driver {
// URL to the spanner pgadapter, or a locally-running spanner emulator with the pgadapter
u := dbtest.GetenvURLOrSkip(t, "SPANNER_POSTGRES_TEST_URL")
drv, err := dbmate.New(u).Driver()
require.NoError(t, err)

return drv.(*Driver)
}

func prepTestPostgresDB(t *testing.T) *sql.DB {
drv := testPostgresDriver(t)

Expand Down Expand Up @@ -64,6 +73,21 @@ func prepRedshiftTestDB(t *testing.T, drv *Driver) *sql.DB {
return db
}

func prepTestSpannerPostgresDB(t *testing.T, drv *Driver) *sql.DB {
// Spanner doesn't allow running `drop database`, so we just drop the migrations
// table instead
db, err := sql.Open("postgres", connectionString(drv.databaseURL))
require.NoError(t, err)

_, migrationsTable, err := drv.quotedMigrationsTableNameParts(db)
require.NoError(t, err)

_, err = db.Exec(fmt.Sprintf("drop table if exists %s", migrationsTable))
require.NoError(t, err)

return db
}

func TestGetDriver(t *testing.T) {
db := dbmate.New(dbtest.MustParseURL(t, "postgres://"))
drvInterface, err := db.Driver()
Expand Down Expand Up @@ -107,6 +131,7 @@ func TestConnectionString(t *testing.T) {
{"postgres://bob:secret@/foo?host=/var/run/postgresql", "postgres://bob:secret@:5432/foo?host=%2Fvar%2Frun%2Fpostgresql"},
// redshift default port is 5439, not 5432
{"redshift://myhost/foo", "postgres://myhost:5439/foo"},
{"spanner-postgres://myhost/foo", "postgres://myhost:5432/foo"},
}

for _, c := range cases {
Expand Down Expand Up @@ -420,6 +445,28 @@ func TestRedshiftCreateMigrationsTable(t *testing.T) {
})
}

func TestSpannerPostgresCreateMigrationsTable(t *testing.T) {
t.Run("default schema", func(t *testing.T) {
drv := testSpannerPostgresDriver(t)
db := prepTestSpannerPostgresDB(t, drv)
defer dbutil.MustClose(db)

// migrations table should not exist
count := 0
err := db.QueryRow("select count(*) from public.schema_migrations").Scan(&count)
require.Error(t, err, "migrations table exists when it shouldn't")
require.Contains(t, err.Error(), "pq: relation \"public.schema_migrations\" does not exist")

// create table
err = drv.CreateMigrationsTable(db)
require.NoError(t, err)

// migrations table should exist
err = db.QueryRow("select count(*) from public.schema_migrations").Scan(&count)
require.NoError(t, err)
})
}

func TestPostgresSelectMigrations(t *testing.T) {
drv := testPostgresDriver(t)
drv.migrationsTableName = "test_migrations"
Expand Down

0 comments on commit 95461d6

Please sign in to comment.