Add support for creating tables and columns with comments (#224)

Update the **create table** and **add column** operations so that they
support adding [Postgres
comments](https://www.postgresql.org/docs/current/sql-comment.html):

* **create table**: comments can be added to the table itself and to
each of its columns.
* **add column**: a comment can be added to the column.

A **create table** migration that includes a comment on the table itself
and on one of its columns looks like this:

```json
{
  "name": "12_create_employees_table",
  "operations": [
    {
      "create_table": {
        "name": "employees",
        "comment": "This is a comment for the employees table",
        "columns": [
          {
            "name": "id",
            "type": "serial",
            "pk": true
          },
          {
            "name": "role",
            "type": "varchar(255)",
            "comment": "This is a comment for the role column"
          }
        ]
      }
    }
  ]
}
```

and an **add column** migration that includes a comment looks like this:

```json
{
  "name": "30_add_column_simple_up",
  "operations": [
    {
      "add_column": {
        "table": "people",
        "up": "'temporary-description'",
        "column": {
          "name": "description",
          "type": "varchar(255)",
          "nullable": false,
          "comment": "This is a comment for the description column"
        }
      }
    }
  ]
}
```

This allows new tables and columns to be created with comments.

Deletion and modification of comments should still be performed with a
raw SQL migration. Until we see a use case that requires versioned
modification/removal of comments, these operations are best performed
directly on the base table with raw SQL.
This commit is contained in:
Andrew Farries 2024-01-10 15:58:57 +00:00 committed by GitHub
parent f1757f31a2
commit 61cc53ab88
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
11 changed files with 218 additions and 2 deletions

View File

@ -698,6 +698,7 @@ An add column operation creates a new column on an existing table.
"column": {
"name": "name of column",
"type": "postgres type",
"comment": "postgres comment for the column",
"nullable": true|false,
"unique": true|false,
"pk": true|false,
@ -911,6 +912,7 @@ where each `column` is defined as:
{
"name": "column name",
"type": "postgres type",
"comment": "postgres comment for the column",
"nullable": true|false,
"unique": true|false,
"pk": true|false,

View File

@ -4,6 +4,7 @@
{
"create_table": {
"name": "employees",
"comment": "This is a comment for the employees table",
"columns": [
{
"name": "id",
@ -12,7 +13,8 @@
},
{
"name": "role",
"type": "varchar(255)"
"type": "varchar(255)",
"comment": "This is a comment for the role column"
}
]
}

View File

@ -8,7 +8,8 @@
"column": {
"name": "description",
"type": "varchar(255)",
"nullable": false
"nullable": false,
"comment": "This is a comment for the description column"
}
}
}

28
pkg/migrations/comment.go Normal file
View File

@ -0,0 +1,28 @@
// SPDX-License-Identifier: Apache-2.0
package migrations
import (
"context"
"database/sql"
"fmt"
"github.com/lib/pq"
)
func addCommentToColumn(ctx context.Context, conn *sql.DB, tableName, columnName, comment string) error {
_, err := conn.ExecContext(ctx, fmt.Sprintf(`COMMENT ON COLUMN %s.%s IS %s`,
pq.QuoteIdentifier(tableName),
pq.QuoteIdentifier(columnName),
pq.QuoteLiteral(comment)))
return err
}
func addCommentToTable(ctx context.Context, conn *sql.DB, tableName, comment string) error {
_, err := conn.ExecContext(ctx, fmt.Sprintf(`COMMENT ON TABLE %s IS %s`,
pq.QuoteIdentifier(tableName),
pq.QuoteLiteral(comment)))
return err
}

View File

@ -21,6 +21,12 @@ func (o *OpAddColumn) Start(ctx context.Context, conn *sql.DB, stateSchema strin
return fmt.Errorf("failed to start add column operation: %w", err)
}
if o.Column.Comment != nil {
if err := addCommentToColumn(ctx, conn, o.Table, TemporaryName(o.Column.Name), *o.Column.Comment); err != nil {
return fmt.Errorf("failed to add comment to column: %w", err)
}
}
if !o.Column.Nullable && o.Column.Default == nil {
if err := addNotNullConstraint(ctx, conn, o.Table, o.Column.Name, TemporaryName(o.Column.Name)); err != nil {
return fmt.Errorf("failed to add not null constraint: %w", err)

View File

@ -47,6 +47,7 @@ func TestAddColumn(t *testing.T) {
Type: "integer",
Nullable: false,
Default: ptr("0"),
Comment: ptr("the age of the user"),
},
},
},
@ -751,3 +752,59 @@ func TestAddColumnWithCheckConstraint(t *testing.T) {
},
}})
}
func TestAddColumnWithComment(t *testing.T) {
t.Parallel()
ExecuteTests(t, TestCases{{
name: "add column",
migrations: []migrations.Migration{
{
Name: "01_add_table",
Operations: migrations.Operations{
&migrations.OpCreateTable{
Name: "users",
Columns: []migrations.Column{
{
Name: "id",
Type: "serial",
Pk: true,
},
{
Name: "name",
Type: "varchar(255)",
Unique: true,
},
},
},
},
},
{
Name: "02_add_column",
Operations: migrations.Operations{
&migrations.OpAddColumn{
Table: "users",
Column: migrations.Column{
Name: "age",
Type: "integer",
Nullable: false,
Default: ptr("0"),
Comment: ptr("the age of the user"),
},
},
},
},
},
afterStart: func(t *testing.T, db *sql.DB) {
// The comment has been added to the underlying column.
columnName := migrations.TemporaryName("age")
ColumnMustHaveComment(t, db, "public", "users", columnName, "the age of the user")
},
afterRollback: func(t *testing.T, db *sql.DB) {
},
afterComplete: func(t *testing.T, db *sql.DB) {
// The comment is still present on the underlying column.
ColumnMustHaveComment(t, db, "public", "users", "age", "the age of the user")
},
}})
}

View File

@ -146,6 +146,20 @@ func ColumnMustHaveType(t *testing.T, db *sql.DB, schema, table, column, expecte
}
}
func ColumnMustHaveComment(t *testing.T, db *sql.DB, schema, table, column, expectedComment string) {
t.Helper()
if !columnHasComment(t, db, schema, table, column, expectedComment) {
t.Fatalf("Expected column %q to have comment %q", column, expectedComment)
}
}
func TableMustHaveComment(t *testing.T, db *sql.DB, schema, table, expectedComment string) {
t.Helper()
if !tableHasComment(t, db, schema, table, expectedComment) {
t.Fatalf("Expected table %q to have comment %q", table, expectedComment)
}
}
func TableMustHaveColumnCount(t *testing.T, db *sql.DB, schema, table string, n int) {
t.Helper()
if !tableMustHaveColumnCount(t, db, schema, table, n) {
@ -400,6 +414,40 @@ func columnHasType(t *testing.T, db *sql.DB, schema, table, column, expectedType
return expectedType == actualType
}
func columnHasComment(t *testing.T, db *sql.DB, schema, table, column, expectedComment string) bool {
t.Helper()
var actualComment string
err := db.QueryRow(fmt.Sprintf(`
SELECT col_description(
%[1]s::regclass,
(SELECT attnum FROM pg_attribute WHERE attname=%[2]s and attrelid=%[1]s::regclass)
)`,
pq.QuoteLiteral(fmt.Sprintf("%s.%s", schema, table)),
pq.QuoteLiteral(column)),
).Scan(&actualComment)
if err != nil {
t.Fatal(err)
}
return expectedComment == actualComment
}
func tableHasComment(t *testing.T, db *sql.DB, schema, table, expectedComment string) bool {
t.Helper()
var actualComment string
err := db.QueryRow(fmt.Sprintf(`
SELECT obj_description(%[1]s::regclass, 'pg_class')`,
pq.QuoteLiteral(fmt.Sprintf("%s.%s", schema, table))),
).Scan(&actualComment)
if err != nil {
t.Fatal(err)
}
return expectedComment == actualComment
}
func MustInsert(t *testing.T, db *sql.DB, schema, version, table string, record map[string]string) {
t.Helper()

View File

@ -22,6 +22,22 @@ func (o *OpCreateTable) Start(ctx context.Context, conn *sql.DB, stateSchema str
return err
}
// Add comments to any columns that have them
for _, col := range o.Columns {
if col.Comment != nil {
if err := addCommentToColumn(ctx, conn, tempName, col.Name, *col.Comment); err != nil {
return fmt.Errorf("failed to add comment to column: %w", err)
}
}
}
// Add comment to the table itself
if o.Comment != nil {
if err := addCommentToTable(ctx, conn, tempName, *o.Comment); err != nil {
return fmt.Errorf("failed to add comment to table: %w", err)
}
}
columns := make(map[string]schema.Column, len(o.Columns))
for _, col := range o.Columns {
columns[col.Name] = schema.Column{

View File

@ -230,6 +230,48 @@ func TestCreateTable(t *testing.T) {
})
},
},
{
name: "create table with column and table comments",
migrations: []migrations.Migration{
{
Name: "01_create_table",
Operations: migrations.Operations{
&migrations.OpCreateTable{
Name: "users",
Comment: ptr("the users table"),
Columns: []migrations.Column{
{
Name: "id",
Type: "serial",
Pk: true,
},
{
Name: "name",
Type: "varchar(255)",
Unique: true,
Comment: ptr("the username"),
},
},
},
},
},
},
afterStart: func(t *testing.T, db *sql.DB) {
tableName := migrations.TemporaryName("users")
// The comment has been added to the underlying table.
TableMustHaveComment(t, db, "public", tableName, "the users table")
// The comment has been added to the underlying column.
ColumnMustHaveComment(t, db, "public", tableName, "name", "the username")
},
afterRollback: func(t *testing.T, db *sql.DB) {
},
afterComplete: func(t *testing.T, db *sql.DB) {
// The comment is still present on the underlying table.
TableMustHaveComment(t, db, "public", "users", "the users table")
// The comment is still present on the underlying column.
ColumnMustHaveComment(t, db, "public", "users", "name", "the username")
},
},
})
}

View File

@ -17,6 +17,9 @@ type Column struct {
// Check constraint for the column
Check *CheckConstraint `json:"check,omitempty"`
// Postgres comment for the column
Comment *string `json:"comment,omitempty"`
// Default value for the column
Default *string `json:"default,omitempty"`
@ -113,6 +116,9 @@ type OpCreateTable struct {
// Columns corresponds to the JSON schema field "columns".
Columns []Column `json:"columns"`
// Postgres comment for the table
Comment *string `json:"comment,omitempty"`
// Name of the table
Name string `json:"name"`
}

View File

@ -56,6 +56,10 @@
"unique": {
"description": "Indicates if the column values must be unique",
"type": "boolean"
},
"comment": {
"description": "Postgres comment for the column",
"type": "string"
}
},
"required": ["name", "nullable", "pk", "type", "unique"],
@ -186,6 +190,10 @@
"name": {
"description": "Name of the table",
"type": "string"
},
"comment": {
"description": "Postgres comment for the table",
"type": "string"
}
},
"required": ["columns", "name"],