Use go embed to load queries from static files (#607)

This commit is contained in:
Dan Sosedoff 2022-12-06 17:41:46 -06:00 committed by GitHub
parent f4b3091666
commit f48cc5f007
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
15 changed files with 247 additions and 243 deletions

View File

@ -11,9 +11,14 @@ jobs:
tests:
name: tests
runs-on: ubuntu-latest
timeout-minutes: 30
strategy:
matrix:
pg_version: [12, 13, 14]
services:
postgres:
image: postgres:12
image: postgres:${{ matrix.pg_version }}
env:
POSTGRES_USER: postgres
POSTGRES_PASSWORD: postgres

View File

@ -176,27 +176,40 @@ func testClientIdleTime(t *testing.T) {
}
func testTest(t *testing.T) {
assert.Equal(t, nil, testClient.Test())
assert.NoError(t, testClient.Test())
}
func testInfo(t *testing.T) {
res, err := testClient.Info()
expected := []string{
"session_user",
"current_user",
"current_database",
"current_schemas",
"inet_client_addr",
"inet_client_port",
"inet_server_addr",
"inet_server_port",
"version",
}
assert.Equal(t, nil, err)
assert.NotEqual(t, nil, res)
res, err := testClient.Info()
assert.NoError(t, err)
assert.Equal(t, expected, res.Columns)
}
func testActivity(t *testing.T) {
res, err := testClient.Activity()
expected := []string{"datid", "pid", "query", "query_start", "state", "client_addr"}
assert.Equal(t, nil, err)
assert.NotEqual(t, nil, res)
res, err := testClient.Activity()
assert.NoError(t, err)
for _, val := range expected {
assert.Contains(t, res.Columns, val)
}
}
func testDatabases(t *testing.T) {
res, err := testClient.Databases()
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Contains(t, res, "booktown")
assert.Contains(t, res, "postgres")
}
@ -232,7 +245,7 @@ func testObjects(t *testing.T) {
"text_sorting",
}
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Equal(t, []string{"schema", "name", "type", "owner", "comment"}, res.Columns)
assert.Equal(t, []string{"public"}, mapKeys(objects))
assert.Equal(t, tables, objects["public"].Tables)
@ -248,8 +261,6 @@ func testObjects(t *testing.T) {
}
func testTable(t *testing.T) {
res, err := testClient.Table("books")
columns := []string{
"column_name",
"data_type",
@ -260,68 +271,60 @@ func testTable(t *testing.T) {
"comment",
}
assert.Equal(t, nil, err)
res, err := testClient.Table("books")
assert.NoError(t, err)
assert.Equal(t, columns, res.Columns)
assert.Equal(t, 4, len(res.Rows))
}
func testTableRows(t *testing.T) {
res, err := testClient.TableRows("books", RowsOptions{})
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Equal(t, 4, len(res.Columns))
assert.Equal(t, 15, len(res.Rows))
}
func testTableInfo(t *testing.T) {
res, err := testClient.TableInfo("books")
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Equal(t, 4, len(res.Columns))
assert.Equal(t, 1, len(res.Rows))
}
func testEstimatedTableRowsCount(t *testing.T) {
var count int64 = 15
res, err := testClient.EstimatedTableRowsCount("books", RowsOptions{})
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Equal(t, []string{"reltuples"}, res.Columns)
assert.Equal(t, []Row{{count}}, res.Rows)
assert.Equal(t, []Row{{int64(15)}}, res.Rows)
}
func testTableRowsCount(t *testing.T) {
var count int64 = 15
res, err := testClient.TableRowsCount("books", RowsOptions{})
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Equal(t, []string{"count"}, res.Columns)
assert.Equal(t, []Row{{count}}, res.Rows)
assert.Equal(t, []Row{{int64(15)}}, res.Rows)
}
func testTableRowsCountWithLargeTable(t *testing.T) {
var count int64 = 100010
testClient.db.MustExec(`CREATE TABLE large_table AS SELECT s FROM generate_Series(1,100010) s;`)
testClient.db.MustExec(`CREATE TABLE large_table AS SELECT s FROM generate_series(1,1000000) s;`)
testClient.db.MustExec(`VACUUM large_table;`)
res, err := testClient.TableRowsCount("large_table", RowsOptions{})
res, err := testClient.TableRowsCount("large_table", RowsOptions{})
assert.Equal(t, nil, err)
assert.Equal(t, []string{"reltuples"}, res.Columns)
assert.Equal(t, []Row{{count}}, res.Rows)
assert.Equal(t, []Row{{int64(1000000)}}, res.Rows)
}
func testTableIndexes(t *testing.T) {
res, err := testClient.TableIndexes("books")
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Equal(t, []string{"index_name", "index_size", "index_definition"}, res.Columns)
assert.Equal(t, 2, len(res.Rows))
}
func testTableConstraints(t *testing.T) {
res, err := testClient.TableConstraints("editions")
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Equal(t, []string{"name", "definition"}, res.Columns)
assert.Equal(t, Row{"pkey", "PRIMARY KEY (isbn)"}, res.Rows[0])
assert.Equal(t, Row{"integrity", "CHECK (book_id IS NOT NULL AND edition IS NOT NULL)"}, res.Rows[1])
@ -352,7 +355,7 @@ func testTableNameWithCamelCase(t *testing.T) {
func testQuery(t *testing.T) {
res, err := testClient.Query("SELECT * FROM books")
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Equal(t, 4, len(res.Columns))
assert.Equal(t, 15, len(res.Rows))
}
@ -360,8 +363,7 @@ func testQuery(t *testing.T) {
func testUpdateQuery(t *testing.T) {
t.Run("updating data", func(t *testing.T) {
// Add new row
_, err := testClient.db.Exec("INSERT INTO books (id, title) VALUES (8888, 'Test Book'), (8889, 'Test Book 2')")
assert.NoError(t, err)
testClient.db.MustExec("INSERT INTO books (id, title) VALUES (8888, 'Test Book'), (8889, 'Test Book 2')")
// Update without return values
res, err := testClient.Query("UPDATE books SET title = 'Foo' WHERE id >= 8888 AND id <= 8889")
@ -379,8 +381,7 @@ func testUpdateQuery(t *testing.T) {
t.Run("deleting data", func(t *testing.T) {
// Add new row
_, err := testClient.db.Exec("INSERT INTO books (id, title) VALUES (9999, 'Test Book')")
assert.NoError(t, err)
testClient.db.MustExec("INSERT INTO books (id, title) VALUES (9999, 'Test Book')")
// Delete the existing row
res, err := testClient.Query("DELETE FROM books WHERE id = 9999")
@ -394,8 +395,7 @@ func testUpdateQuery(t *testing.T) {
assert.Equal(t, int64(0), res.Rows[0][0])
// Delete with returning value
_, err = testClient.db.Exec("INSERT INTO books (id, title) VALUES (9999, 'Test Book')")
assert.NoError(t, err)
testClient.db.MustExec("INSERT INTO books (id, title) VALUES (9999, 'Test Book')")
res, err = testClient.Query("DELETE FROM books WHERE id = 9999 RETURNING id")
assert.NoError(t, err)
@ -405,74 +405,78 @@ func testUpdateQuery(t *testing.T) {
func testQueryError(t *testing.T) {
res, err := testClient.Query("SELCT * FROM books")
assert.NotEqual(t, nil, err)
assert.NotNil(t, err)
assert.Equal(t, "pq: syntax error at or near \"SELCT\"", err.Error())
assert.Equal(t, true, res == nil)
assert.Nil(t, res)
}
func testQueryInvalidTable(t *testing.T) {
res, err := testClient.Query("SELECT * FROM books2")
assert.NotEqual(t, nil, err)
assert.NotNil(t, err)
assert.Equal(t, "pq: relation \"books2\" does not exist", err.Error())
assert.Equal(t, true, res == nil)
assert.Nil(t, res)
}
func testTableRowsOrderEscape(t *testing.T) {
rows, err := testClient.TableRows("dummies", RowsOptions{SortColumn: "isDummy"})
assert.Equal(t, nil, err)
assert.NoError(t, err)
assert.Equal(t, 2, len(rows.Rows))
rows, err = testClient.TableRows("dummies", RowsOptions{SortColumn: "isdummy"})
assert.NotEqual(t, nil, err)
assert.NotNil(t, err)
assert.Equal(t, `pq: column "isdummy" does not exist`, err.Error())
assert.Equal(t, true, rows == nil)
assert.Nil(t, rows)
}
func testResultJSON(t *testing.T) {
result, err := testClient.Query("SELECT 'NaN'::float AS value;")
func testResult(t *testing.T) {
t.Run("json", func(t *testing.T) {
result, err := testClient.Query("SELECT * FROM books LIMIT 1")
assert.NoError(t, err)
assert.Equal(t, `[{"author_id":4156,"id":7808,"subject_id":9,"title":"The Shining"}]`, string(result.JSON()))
assert.NoError(t, err)
assert.Equal(t, `[{"value":null}]`, string(result.JSON()))
}
result, err = testClient.Query("SELECT 'NaN'::float AS value;")
assert.NoError(t, err)
assert.Equal(t, `[{"value":null}]`, string(result.JSON()))
})
func testResultCsv(t *testing.T) {
res, _ := testClient.Query("SELECT * FROM books ORDER BY id ASC LIMIT 1")
csv := res.CSV()
t.Run("csv", func(t *testing.T) {
expected := "id,title,author_id,subject_id\n156,The Tell-Tale Heart,115,9\n"
expected := "id,title,author_id,subject_id\n156,The Tell-Tale Heart,115,9\n"
assert.Equal(t, expected, string(csv))
res, err := testClient.Query("SELECT * FROM books ORDER BY id ASC LIMIT 1")
assert.NoError(t, err)
assert.Equal(t, expected, string(res.CSV()))
})
}
func testHistory(t *testing.T) {
_, err := testClient.Query("SELECT * FROM books WHERE id = 12345")
query := testClient.History[len(testClient.History)-1].Query
assert.Equal(t, nil, err)
assert.Equal(t, "SELECT * FROM books WHERE id = 12345", query)
}
func testHistoryError(t *testing.T) {
_, err := testClient.Query("SELECT * FROM books123")
query := testClient.History[len(testClient.History)-1].Query
assert.NotEqual(t, nil, err)
assert.NotEqual(t, "SELECT * FROM books123", query)
}
func testHistoryUniqueness(t *testing.T) {
url := fmt.Sprintf("postgres://%s@%s:%s/%s?sslmode=disable", serverUser, serverHost, serverPort, serverDatabase)
client, _ := NewFromUrl(url, nil)
for i := 0; i < 3; i++ {
_, err := client.Query("SELECT * FROM books WHERE id = 1")
t.Run("success", func(t *testing.T) {
_, err := testClient.Query("SELECT * FROM books WHERE id = 12345")
query := testClient.History[len(testClient.History)-1].Query
assert.NoError(t, err)
}
assert.Equal(t, "SELECT * FROM books WHERE id = 12345", query)
})
assert.Equal(t, 1, len(client.History))
assert.Equal(t, "SELECT * FROM books WHERE id = 1", client.History[0].Query)
t.Run("failed query", func(t *testing.T) {
_, err := testClient.Query("SELECT * FROM books123")
query := testClient.History[len(testClient.History)-1].Query
assert.NotNil(t, err)
assert.NotEqual(t, "SELECT * FROM books123", query)
})
t.Run("unique queries", func(t *testing.T) {
url := fmt.Sprintf("postgres://%s@%s:%s/%s?sslmode=disable", serverUser, serverHost, serverPort, serverDatabase)
client, err := NewFromUrl(url, nil)
assert.NoError(t, err)
for i := 0; i < 3; i++ {
_, err := client.Query("SELECT * FROM books WHERE id = 1")
assert.NoError(t, err)
}
assert.Equal(t, 1, len(client.History))
assert.Equal(t, "SELECT * FROM books WHERE id = 1", client.History[0].Query)
})
}
func testReadOnlyMode(t *testing.T) {
@ -540,11 +544,8 @@ func TestAll(t *testing.T) {
testQueryError(t)
testQueryInvalidTable(t)
testTableRowsOrderEscape(t)
testResultJSON(t)
testResultCsv(t)
testResult(t)
testHistory(t)
testHistoryUniqueness(t)
testHistoryError(t)
testReadOnlyMode(t)
testDumpExport(t)

View File

@ -74,6 +74,8 @@ func (res *Result) PostProcess() {
res.Rows[i][j] = encodeBinaryData([]byte(val), BinaryCodec)
}
case time.Time:
// RFC 3339 is clear that years are 4 digits exactly.
// See golang.org/issue/4556#c15 for more discussion.
if val.Year() < 0 || val.Year() >= 10000 {
res.Rows[i][j] = "ERR: INVALID_DATE"
} else {

View File

@ -1,162 +1,44 @@
package statements
const (
Databases = `
SELECT
datname
FROM
pg_database
WHERE
NOT datistemplate
ORDER BY
datname ASC`
// ---------------------------------------------------------------------------
Schemas = `
SELECT
schema_name
FROM
information_schema.schemata
ORDER BY
schema_name ASC`
// ---------------------------------------------------------------------------
Info = `
SELECT
session_user,
current_user,
current_database(),
current_schemas(false),
inet_client_addr(),
inet_client_port(),
inet_server_addr(),
inet_server_port(),
version()`
// ---------------------------------------------------------------------------
EstimatedTableRowCount = `
SELECT
reltuples
FROM
pg_class
WHERE
oid = ('"' || $1::text || '"."' || $2::text || '"')::regclass
`
// ---------------------------------------------------------------------------
TableIndexes = `
SELECT
indexname AS index_name,
pg_size_pretty(pg_table_size(indexname::regclass)) AS index_size,
indexdef AS index_definition
FROM
pg_indexes
WHERE
schemaname = $1 AND
tablename = $2`
// ---------------------------------------------------------------------------
TableConstraints = `
SELECT
conname as name,
pg_get_constraintdef(c.oid, true) as definition
FROM
pg_constraint c
JOIN
pg_namespace n ON n.oid = c.connamespace
JOIN
pg_class cl ON cl.oid = c.conrelid
WHERE
n.nspname = $1 AND
relname = $2
ORDER BY
contype desc`
// ---------------------------------------------------------------------------
TableInfo = `
SELECT
pg_size_pretty(pg_table_size($1)) AS data_size,
pg_size_pretty(pg_indexes_size($1)) AS index_size,
pg_size_pretty(pg_total_relation_size($1)) AS total_size,
(SELECT reltuples FROM pg_class WHERE oid = $1::regclass) AS rows_count`
TableInfoCockroach = `
SELECT
'n/a' AS data_size,
'n/a' AS index_size,
'n/a' AS total_size,
'n/a' AS rows_count`
// ---------------------------------------------------------------------------
TableSchema = `
SELECT
column_name,
data_type,
is_nullable,
character_maximum_length,
character_set_catalog,
column_default,
pg_catalog.col_description(('"' || $1::text || '"."' || $2::text || '"')::regclass::oid, ordinal_position) as comment
FROM
information_schema.columns
WHERE
table_schema = $1 AND
table_name = $2`
// ---------------------------------------------------------------------------
MaterializedView = `
SELECT
attname as column_name,
atttypid::regtype AS data_type,
(case when attnotnull IS TRUE then 'NO' else 'YES' end) as is_nullable,
null as character_maximum_length,
null as character_set_catalog,
null as column_default
FROM
pg_attribute
WHERE
attrelid = $1::regclass AND
attnum > 0 AND
NOT attisdropped`
// ---------------------------------------------------------------------------
Objects = `
SELECT
n.nspname as "schema",
c.relname as "name",
CASE c.relkind
WHEN 'r' THEN 'table'
WHEN 'v' THEN 'view'
WHEN 'm' THEN 'materialized_view'
WHEN 'i' THEN 'index'
WHEN 'S' THEN 'sequence'
WHEN 's' THEN 'special'
WHEN 'f' THEN 'foreign_table'
END as "type",
pg_catalog.pg_get_userbyid(c.relowner) as "owner",
pg_catalog.obj_description(c.oid) as "comment"
FROM
pg_catalog.pg_class c
LEFT JOIN
pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE
c.relkind IN ('r','v','m','S','s','') AND
n.nspname !~ '^pg_toast' AND
n.nspname NOT IN ('information_schema', 'pg_catalog') AND
has_schema_privilege(n.nspname, 'USAGE')
ORDER BY 1, 2`
import (
_ "embed"
)
var (
//go:embed sql/databases.sql
Databases string
//go:embed sql/schemas.sql
Schemas string
//go:embed sql/info.sql
Info string
//go:embed sql/estimated_row_count.sql
EstimatedTableRowCount string
//go:embed sql/table_indexes.sql
TableIndexes string
//go:embed sql/table_constraints.sql
TableConstraints string
//go:embed sql/table_info.sql
TableInfo string
//go:embed sql/table_info_cockroach.sql
TableInfoCockroach string
//go:embed sql/table_schema.sql
TableSchema string
//go:embed sql/materialized_view.sql
MaterializedView string
//go:embed sql/objects.sql
Objects string
// Activity queries for specific PG versions
Activity = map[string]string{
"default": "SELECT * FROM pg_stat_activity WHERE datname = current_database()",
"9.1": "SELECT datname, current_query, waiting, query_start, procpid as pid, datid, application_name, client_addr FROM pg_stat_activity WHERE datname = current_database()",

View File

@ -0,0 +1,8 @@
SELECT
datname
FROM
pg_database
WHERE
NOT datistemplate
ORDER BY
datname ASC

View File

@ -0,0 +1,6 @@
SELECT
reltuples
FROM
pg_class
WHERE
oid = ('"' || $1::text || '"."' || $2::text || '"')::regclass

View File

@ -0,0 +1,10 @@
SELECT
session_user,
current_user,
current_database(),
current_schemas(false),
inet_client_addr(),
inet_client_port(),
inet_server_addr(),
inet_server_port(),
version()

View File

@ -0,0 +1,13 @@
SELECT
attname AS column_name,
atttypid::regtype AS data_type,
(CASE WHEN attnotnull IS TRUE THEN 'NO' ELSE 'YES' END) AS is_nullable,
NULL AS character_maximum_length,
NULL AS character_set_catalog,
NULL AS column_default
FROM
pg_attribute
WHERE
attrelid = $1::regclass
AND attnum > 0
AND NOT attisdropped

View File

@ -0,0 +1,25 @@
SELECT
n.nspname AS schema,
c.relname AS name,
CASE c.relkind
WHEN 'r' THEN 'table'
WHEN 'v' THEN 'view'
WHEN 'm' THEN 'materialized_view'
WHEN 'i' THEN 'index'
WHEN 'S' THEN 'sequence'
WHEN 's' THEN 'special'
WHEN 'f' THEN 'foreign_table'
END AS type,
pg_catalog.pg_get_userbyid(c.relowner) AS owner,
pg_catalog.obj_description(c.oid) AS comment
FROM
pg_catalog.pg_class c
LEFT JOIN
pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE
c.relkind IN ('r','v','m','S','s','')
AND n.nspname !~ '^pg_toast'
AND n.nspname NOT IN ('information_schema', 'pg_catalog')
AND has_schema_privilege(n.nspname, 'USAGE')
ORDER BY
1, 2

View File

@ -0,0 +1,6 @@
SELECT
schema_name
FROM
information_schema.schemata
ORDER BY
schema_name ASC

View File

@ -0,0 +1,14 @@
SELECT
conname AS name,
pg_get_constraintdef(c.oid, true) AS definition
FROM
pg_constraint c
JOIN
pg_namespace n ON n.oid = c.connamespace
JOIN
pg_class cl ON cl.oid = c.conrelid
WHERE
n.nspname = $1
AND relname = $2
ORDER BY
contype DESC

View File

@ -0,0 +1,9 @@
SELECT
indexname AS index_name,
pg_size_pretty(pg_table_size((schemaname || '.' || indexname)::regclass)) AS index_size,
indexdef AS index_definition
FROM
pg_indexes
WHERE
schemaname = $1
AND tablename = $2

View File

@ -0,0 +1,5 @@
SELECT
pg_size_pretty(pg_table_size($1)) AS data_size,
pg_size_pretty(pg_indexes_size($1)) AS index_size,
pg_size_pretty(pg_total_relation_size($1)) AS total_size,
(SELECT reltuples FROM pg_class WHERE oid = $1::regclass) AS rows_count

View File

@ -0,0 +1,5 @@
SELECT
'n/a' AS data_size,
'n/a' AS index_size,
'n/a' AS total_size,
'n/a' AS rows_count

View File

@ -0,0 +1,13 @@
SELECT
column_name,
data_type,
is_nullable,
character_maximum_length,
character_set_catalog,
column_default,
pg_catalog.col_description(('"' || $1::text || '"."' || $2::text || '"')::regclass::oid, ordinal_position) as comment
FROM
information_schema.columns
WHERE
table_schema = $1
AND table_name = $2