diff --git a/docs/operations/create_table.mdx b/docs/operations/create_table.mdx
index dd559c98..e04817ae 100644
--- a/docs/operations/create_table.mdx
+++ b/docs/operations/create_table.mdx
@@ -9,7 +9,8 @@ description: A create table operation creates a new table in the database.
{
"create_table": {
"name": "name of new table",
- "columns": [...]
+ "columns": [...],
+ "constraints": [...]
}
}
```
@@ -40,6 +41,26 @@ Each `column` is defined as:
Default values are subject to the usual rules for quoting SQL expressions. In particular, string literals should be surrounded with single quotes.
+Each `constraint` is defined as:
+
+```json
+{
+ "name": "constraint name",
+ "type": "constraint type",
+ "columns": ["list", "of", "columns"],
+ "nulls_not_distinct": true|false,
+ "deferrable": true|false,
+ "initially_deferred": true|false,
+ "index_parameters": {
+ "tablespace": "index_tablespace",
+ "storage_parameters": "parameter=value",
+ "include_columns": ["list", "of", "columns", "included in index"]
+ },
+},
+```
+
+Supported constraint types: `unique`.
+
## Examples
### Create multiple tables
@@ -98,3 +119,9 @@ Create a table with a `CHECK` constraint on one column:
Create a table with different `DEFAULT` values:
+
+### Create a table with table level unique constraint
+
+Create a table with table level constraints:
+
+
\ No newline at end of file
diff --git a/examples/.ledger b/examples/.ledger
index c59c07f5..9f415628 100644
--- a/examples/.ledger
+++ b/examples/.ledger
@@ -47,3 +47,4 @@
47_add_table_foreign_key_constraint.json
48_drop_tickets_check.json
49_unset_not_null_on_indexed_column.json
+50_create_table_with_table_constraint.json
diff --git a/examples/50_create_table_with_table_constraint.json b/examples/50_create_table_with_table_constraint.json
new file mode 100644
index 00000000..08d041f1
--- /dev/null
+++ b/examples/50_create_table_with_table_constraint.json
@@ -0,0 +1,43 @@
+{
+ "name": "50_create_table_with_table_constraint",
+ "operations": [
+ {
+ "create_table": {
+ "name": "phonebook",
+ "columns": [
+ {
+ "name": "id",
+ "type": "serial",
+ "pk": true
+ },
+ {
+ "name": "name",
+ "type": "varchar(255)"
+ },
+ {
+ "name": "city",
+ "type": "varchar(255)"
+ },
+ {
+ "name": "phone",
+ "type": "varchar(255)"
+ }
+ ],
+ "constraints": [
+ {
+ "name": "unique_numbers",
+ "type": "unique",
+ "columns": [
+ "phone"
+ ],
+ "index_parameters": {
+ "include_columns": [
+ "name"
+ ]
+ }
+ }
+ ]
+ }
+ }
+ ]
+}
diff --git a/pkg/migrations/op_create_table.go b/pkg/migrations/op_create_table.go
index 833c6d21..a2b85b4a 100644
--- a/pkg/migrations/op_create_table.go
+++ b/pkg/migrations/op_create_table.go
@@ -22,10 +22,16 @@ func (o *OpCreateTable) Start(ctx context.Context, conn db.DB, latestSchema stri
return nil, fmt.Errorf("failed to create columns SQL: %w", err)
}
+ constraintsSQL, err := constraintsToSQL(o.Constraints)
+ if err != nil {
+ return nil, fmt.Errorf("failed to create constraints SQL: %w", err)
+ }
+
// Create the table
- _, err = conn.ExecContext(ctx, fmt.Sprintf("CREATE TABLE %s (%s)",
+ _, err = conn.ExecContext(ctx, fmt.Sprintf("CREATE TABLE %s (%s %s)",
pq.QuoteIdentifier(o.Name),
- columnsSQL))
+ columnsSQL,
+ constraintsSQL))
if err != nil {
return nil, err
}
@@ -102,6 +108,22 @@ func (o *OpCreateTable) Validate(ctx context.Context, s *schema.Schema) error {
}
}
+ for _, c := range o.Constraints {
+ if c.Name == "" {
+ return FieldRequiredError{Name: "name"}
+ }
+ if err := ValidateIdentifierLength(c.Name); err != nil {
+ return fmt.Errorf("invalid constraint: %w", err)
+ }
+
+ switch c.Type { //nolint:gocritic // more cases are coming soon
+ case ConstraintTypeUnique:
+ if len(c.Columns) == 0 {
+ return FieldRequiredError{Name: "columns"}
+ }
+ }
+ }
+
// Update the schema to ensure that the new table is visible to validation of
// subsequent operations.
o.updateSchema(s)
@@ -118,9 +140,23 @@ func (o *OpCreateTable) updateSchema(s *schema.Schema) *schema.Schema {
Name: col.Name,
}
}
+ var uniqueConstraints map[string]*schema.UniqueConstraint
+ for _, c := range o.Constraints {
+ switch c.Type { //nolint:gocritic // more cases are coming soon
+ case ConstraintTypeUnique:
+ if uniqueConstraints == nil {
+ uniqueConstraints = make(map[string]*schema.UniqueConstraint)
+ }
+ uniqueConstraints[c.Name] = &schema.UniqueConstraint{
+ Name: c.Name,
+ Columns: c.Columns,
+ }
+ }
+ }
s.AddTable(o.Name, &schema.Table{
- Name: o.Name,
- Columns: columns,
+ Name: o.Name,
+ Columns: columns,
+ UniqueConstraints: uniqueConstraints,
})
return s
@@ -150,3 +186,88 @@ func columnsToSQL(cols []Column, tr SQLTransformer) (string, error) {
}
return sql, nil
}
+
+func constraintsToSQL(constraints []Constraint) (string, error) {
+ constraintsSQL := make([]string, len(constraints))
+ for i, c := range constraints {
+ writer := &ConstraintSQLWriter{
+ Name: c.Name,
+ Columns: c.Columns,
+ InitiallyDeferred: c.InitiallyDeferred,
+ Deferrable: c.Deferrable,
+ }
+ if c.IndexParameters != nil {
+ writer.IncludeColumns = c.IndexParameters.IncludeColumns
+ writer.StorageParameters = c.IndexParameters.StorageParameters
+ writer.Tablespace = c.IndexParameters.Tablespace
+ }
+
+ switch c.Type { //nolint:gocritic // more cases are coming soon
+ case ConstraintTypeUnique:
+ constraintsSQL[i] = writer.WriteUnique(c.NullsNotDistinct)
+ }
+ }
+ if len(constraintsSQL) == 0 {
+ return "", nil
+ }
+ return ", " + strings.Join(constraintsSQL, ", "), nil
+}
+
+type ConstraintSQLWriter struct {
+ Name string
+ Columns []string
+ InitiallyDeferred bool
+ Deferrable bool
+
+ // unique, exclude, primary key constraints support the following options
+ IncludeColumns []string
+ StorageParameters string
+ Tablespace string
+}
+
+func (w *ConstraintSQLWriter) WriteUnique(nullsNotDistinct bool) string {
+ var constraint string
+ if w.Name != "" {
+ constraint = fmt.Sprintf("CONSTRAINT %s ", pq.QuoteIdentifier(w.Name))
+ }
+ nullsDistinct := ""
+ if nullsNotDistinct {
+ nullsDistinct = "NULLS NOT DISTINCT"
+ }
+ constraint += fmt.Sprintf("UNIQUE %s (%s)", nullsDistinct, strings.Join(quoteColumnNames(w.Columns), ", "))
+ constraint += w.addIndexParameters()
+ constraint += w.addDeferrable()
+ return constraint
+}
+
+func (w *ConstraintSQLWriter) addIndexParameters() string {
+ constraint := ""
+ if len(w.IncludeColumns) != 0 {
+ constraint += fmt.Sprintf(" INCLUDE (%s)", strings.Join(quoteColumnNames(w.IncludeColumns), ", "))
+ }
+ if w.StorageParameters != "" {
+ constraint += fmt.Sprintf(" WITH (%s)", w.StorageParameters)
+ }
+ if w.Tablespace != "" {
+ constraint += fmt.Sprintf(" USING INDEX TABLESPACE %s", w.Tablespace)
+ }
+ return constraint
+}
+
+func (w *ConstraintSQLWriter) addDeferrable() string {
+ if !w.InitiallyDeferred && !w.Deferrable {
+ return ""
+ }
+ deferrable := ""
+ if w.Deferrable {
+ deferrable += " DEFERRABLE"
+ } else {
+ deferrable += " NOT DEFERRABLE"
+ }
+ if w.InitiallyDeferred {
+ deferrable += " INITIALLY DEFERRED"
+ } else {
+ deferrable += " INITIALLY IMMEDIATE"
+ }
+ return deferrable
+}
diff --git a/pkg/migrations/op_create_table_test.go b/pkg/migrations/op_create_table_test.go
index 8d47d6ef..bab8ce3b 100644
--- a/pkg/migrations/op_create_table_test.go
+++ b/pkg/migrations/op_create_table_test.go
@@ -483,6 +483,70 @@ func TestCreateTable(t *testing.T) {
ColumnMustHaveComment(t, db, schema, "users", "name", "the username")
},
},
+ {
+ name: "create table with a unique table constraint",
+ migrations: []migrations.Migration{
+ {
+ Name: "01_create_table",
+ Operations: migrations.Operations{
+ &migrations.OpCreateTable{
+ Name: "users",
+ Columns: []migrations.Column{
+ {
+ Name: "id",
+ Type: "serial",
+ Pk: true,
+ },
+ {
+ Name: "name",
+ Type: "text",
+ },
+ },
+ Constraints: []migrations.Constraint{
+ {
+ Name: "unique_name",
+ Type: migrations.ConstraintTypeUnique,
+ Columns: []string{
+ "name",
+ },
+ },
+ },
+ },
+ },
+ },
+ },
+ afterStart: func(t *testing.T, db *sql.DB, schema string) {
+ // The unique constraint exists on the new table.
+ UniqueConstraintMustExist(t, db, schema, "users", "unique_name")
+
+ // Inserting a row into the table succeeds when the unique constraint is satisfied.
+ MustInsert(t, db, schema, "01_create_table", "users", map[string]string{
+ "name": "alice",
+ })
+
+ // Inserting a row into the table fails when the unique constraint is not satisfied.
+ MustNotInsert(t, db, schema, "01_create_table", "users", map[string]string{
+ "name": "alice",
+ }, testutils.UniqueViolationErrorCode)
+ },
+ afterRollback: func(t *testing.T, db *sql.DB, schema string) {
+ // The table has been dropped, so the unique constraint is gone.
+ },
+ afterComplete: func(t *testing.T, db *sql.DB, schema string) {
+ // The check constraint exists on the new table.
+ UniqueConstraintMustExist(t, db, schema, "users", "unique_name")
+
+ // Inserting a row into the table succeeds when the unique constraint is satisfied.
+ MustInsert(t, db, schema, "01_create_table", "users", map[string]string{
+ "name": "bobby",
+ })
+
+ // Inserting a row into the table fails when the unique constraint is not satisfied.
+ MustNotInsert(t, db, schema, "01_create_table", "users", map[string]string{
+ "name": "bobby",
+ }, testutils.UniqueViolationErrorCode)
+ },
+ },
})
}
@@ -601,6 +665,38 @@ func TestCreateTableValidation(t *testing.T) {
},
wantStartErr: migrations.InvalidIdentifierLengthError{Name: invalidName},
},
+ {
+ name: "missing column list in unique constraint",
+ migrations: []migrations.Migration{
+ {
+ Name: "01_create_table",
+ Operations: migrations.Operations{
+ &migrations.OpCreateTable{
+ Name: "table1",
+ Columns: []migrations.Column{
+ {
+ Name: "id",
+ Type: "serial",
+ Pk: true,
+ },
+ {
+ Name: "name",
+ Type: "varchar(255)",
+ Unique: true,
+ },
+ },
+ Constraints: []migrations.Constraint{
+ {
+ Name: "unique_name",
+ Type: migrations.ConstraintTypeUnique,
+ },
+ },
+ },
+ },
+ },
+ },
+ wantStartErr: migrations.FieldRequiredError{Name: "columns"},
+ },
})
}
diff --git a/pkg/migrations/types.go b/pkg/migrations/types.go
index 888d1909..39d9dca2 100644
--- a/pkg/migrations/types.go
+++ b/pkg/migrations/types.go
@@ -44,6 +44,45 @@ type Column struct {
Unique bool `json:"unique,omitempty"`
}
+// Constraint definition
+type Constraint struct {
+ // Columns to add constraint to
+ Columns []string `json:"columns,omitempty"`
+
+ // Deferable constraint
+ Deferrable bool `json:"deferrable,omitempty"`
+
+ // IndexParameters corresponds to the JSON schema field "index_parameters".
+ IndexParameters *ConstraintIndexParameters `json:"index_parameters,omitempty"`
+
+ // Initially deferred constraint
+ InitiallyDeferred bool `json:"initially_deferred,omitempty"`
+
+ // Name of the constraint
+ Name string `json:"name"`
+
+ // Nulls not distinct constraint
+ NullsNotDistinct bool `json:"nulls_not_distinct,omitempty"`
+
+ // Type of the constraint
+ Type ConstraintType `json:"type"`
+}
+
+type ConstraintIndexParameters struct {
+ // IncludeColumns corresponds to the JSON schema field "include_columns".
+ IncludeColumns []string `json:"include_columns,omitempty"`
+
+ // StorageParameters corresponds to the JSON schema field "storage_parameters".
+ StorageParameters string `json:"storage_parameters,omitempty"`
+
+ // Tablespace corresponds to the JSON schema field "tablespace".
+ Tablespace string `json:"tablespace,omitempty"`
+}
+
+type ConstraintType string
+
+const ConstraintTypeUnique ConstraintType = "unique"
+
// Foreign key reference definition
type ForeignKeyReference struct {
// Name of the referenced column
@@ -212,6 +251,9 @@ type OpCreateTable struct {
// Postgres comment for the table
Comment *string `json:"comment,omitempty"`
+ // Constraints corresponds to the JSON schema field "constraints".
+ Constraints []Constraint `json:"constraints,omitempty"`
+
// Name of the table
Name string `json:"name"`
}
diff --git a/pkg/sql2pgroll/create_table.go b/pkg/sql2pgroll/create_table.go
index 74a5792f..3e799285 100644
--- a/pkg/sql2pgroll/create_table.go
+++ b/pkg/sql2pgroll/create_table.go
@@ -19,9 +19,10 @@ func convertCreateStmt(stmt *pgq.CreateStmt) (migrations.Operations, error) {
// Convert the table elements - table elements can be:
// - Column definitions
- // - Table constraints (not supported)
+ // - Table constraints
// - LIKE clauses (not supported)
var columns []migrations.Column
+ var constraints []migrations.Constraint
for _, elt := range stmt.TableElts {
switch elt.Node.(type) {
case *pgq.Node_ColumnDef:
@@ -33,6 +34,15 @@ func convertCreateStmt(stmt *pgq.CreateStmt) (migrations.Operations, error) {
return nil, nil
}
columns = append(columns, *column)
+ case *pgq.Node_Constraint:
+ constraint, err := convertConstraint(elt.GetConstraint())
+ if err != nil {
+ return nil, fmt.Errorf("error converting table constraint: %w", err)
+ }
+ if constraint == nil {
+ return nil, nil
+ }
+ constraints = append(constraints, *constraint)
default:
return nil, nil
}
@@ -40,8 +50,9 @@ func convertCreateStmt(stmt *pgq.CreateStmt) (migrations.Operations, error) {
return migrations.Operations{
&migrations.OpCreateTable{
- Name: getQualifiedRelationName(stmt.GetRelation()),
- Columns: columns,
+ Name: getQualifiedRelationName(stmt.GetRelation()),
+ Columns: columns,
+ Constraints: constraints,
},
}, nil
}
@@ -189,6 +200,58 @@ func convertColumnDef(tableName string, col *pgq.ColumnDef) (*migrations.Column,
}, nil
}
+func convertConstraint(c *pgq.Constraint) (*migrations.Constraint, error) {
+ var constraintType migrations.ConstraintType
+ var nullsNotDistinct bool
+
+ switch c.Contype {
+ case pgq.ConstrType_CONSTR_UNIQUE:
+ constraintType = migrations.ConstraintTypeUnique
+ nullsNotDistinct = c.NullsNotDistinct
+ default:
+ return nil, nil
+ }
+
+ columns := make([]string, len(c.Keys))
+ for i, key := range c.Keys {
+ columns[i] = key.GetString_().Sval
+ }
+
+ including := make([]string, len(c.Including))
+ for i, include := range c.Including {
+ including[i] = include.GetString_().Sval
+ }
+
+ var storageParams string
+ var err error
+ if len(c.GetOptions()) > 0 {
+ storageParams, err = pgq.DeparseRelOptions(c.GetOptions())
+ if err != nil {
+ return nil, fmt.Errorf("parsing options: %w", err)
+ }
+ storageParams = storageParams[1 : len(storageParams)-1]
+ }
+
+ var indexParameters *migrations.ConstraintIndexParameters
+ if storageParams != "" || c.Indexspace != "" || len(including) != 0 {
+ indexParameters = &migrations.ConstraintIndexParameters{
+ StorageParameters: storageParams,
+ Tablespace: c.Indexspace,
+ IncludeColumns: including,
+ }
+ }
+
+ return &migrations.Constraint{
+ Name: c.Conname,
+ Type: constraintType,
+ Columns: columns,
+ NullsNotDistinct: nullsNotDistinct,
+ Deferrable: c.Deferrable,
+ InitiallyDeferred: c.Initdeferred,
+ IndexParameters: indexParameters,
+ }, nil
+}
+
// canConvertColumnDef returns true iff `col` can be converted to a pgroll
// `Column` definition.
func canConvertColumnDef(col *pgq.ColumnDef) bool {
diff --git a/pkg/sql2pgroll/create_table_test.go b/pkg/sql2pgroll/create_table_test.go
index b86b9bbe..5003a2b9 100644
--- a/pkg/sql2pgroll/create_table_test.go
+++ b/pkg/sql2pgroll/create_table_test.go
@@ -164,6 +164,14 @@ func TestConvertCreateTableStatements(t *testing.T) {
sql: "CREATE TABLE foo(a serial PRIMARY KEY, b int DEFAULT 100 CHECK (b > 0), c text NOT NULL UNIQUE)",
expectedOp: expect.CreateTableOp21,
},
+ {
+ sql: "CREATE TABLE foo(a serial PRIMARY KEY, b text, c text, UNIQUE (b, c))",
+ expectedOp: expect.CreateTableOp22,
+ },
+ {
+ sql: "CREATE TABLE foo(b text, c text, UNIQUE (b) INCLUDE (c) WITH (fillfactor = 70) USING INDEX TABLESPACE my_tablespace)",
+ expectedOp: expect.CreateTableOp23,
+ },
}
for _, tc := range tests {
@@ -232,11 +240,9 @@ func TestUnconvertableCreateTableStatements(t *testing.T) {
// Table constraints, named and unnamed, are not supported
"CREATE TABLE foo(a int, CONSTRAINT foo_check CHECK (a > 0))",
- "CREATE TABLE foo(a int, CONSTRAINT foo_unique UNIQUE (a))",
"CREATE TABLE foo(a int, CONSTRAINT foo_pk PRIMARY KEY (a))",
"CREATE TABLE foo(a int, CONSTRAINT foo_fk FOREIGN KEY (a) REFERENCES bar(b))",
"CREATE TABLE foo(a int, CHECK (a > 0))",
- "CREATE TABLE foo(a int, UNIQUE (a))",
"CREATE TABLE foo(a int, PRIMARY KEY (a))",
"CREATE TABLE foo(a int, FOREIGN KEY (a) REFERENCES bar(b))",
diff --git a/pkg/sql2pgroll/expect/create_table.go b/pkg/sql2pgroll/expect/create_table.go
index dd86fdf6..e821f11d 100644
--- a/pkg/sql2pgroll/expect/create_table.go
+++ b/pkg/sql2pgroll/expect/create_table.go
@@ -294,3 +294,63 @@ var CreateTableOp21 = &migrations.OpCreateTable{
},
},
}
+
+var CreateTableOp22 = &migrations.OpCreateTable{
+ Name: "foo",
+ Columns: []migrations.Column{
+ {
+ Name: "a",
+ Type: "serial",
+ Pk: true,
+ },
+ {
+ Name: "b",
+ Type: "text",
+ Nullable: true,
+ },
+ {
+ Name: "c",
+ Type: "text",
+ Nullable: true,
+ },
+ },
+ Constraints: []migrations.Constraint{
+ {
+ Type: migrations.ConstraintTypeUnique,
+ Columns: []string{"b", "c"},
+ NullsNotDistinct: false,
+ Deferrable: false,
+ InitiallyDeferred: false,
+ },
+ },
+}
+
+var CreateTableOp23 = &migrations.OpCreateTable{
+ Name: "foo",
+ Columns: []migrations.Column{
+ {
+ Name: "b",
+ Type: "text",
+ Nullable: true,
+ },
+ {
+ Name: "c",
+ Type: "text",
+ Nullable: true,
+ },
+ },
+ Constraints: []migrations.Constraint{
+ {
+ Type: migrations.ConstraintTypeUnique,
+ Columns: []string{"b"},
+ NullsNotDistinct: false,
+ Deferrable: false,
+ InitiallyDeferred: false,
+ IndexParameters: &migrations.ConstraintIndexParameters{
+ IncludeColumns: []string{"c"},
+ StorageParameters: "fillfactor=70",
+ Tablespace: "my_tablespace",
+ },
+ },
+ },
+}
diff --git a/schema.json b/schema.json
index 4a35ee07..7ff33f85 100644
--- a/schema.json
+++ b/schema.json
@@ -98,6 +98,65 @@
"type": "string",
"enum": ["NO ACTION", "RESTRICT", "CASCADE", "SET NULL", "SET DEFAULT"]
},
+ "Constraint": {
+ "additionalProperties": false,
+ "description": "Constraint definition",
+ "properties": {
+ "name": {
+ "description": "Name of the constraint",
+ "type": "string"
+ },
+ "columns": {
+ "description": "Columns to add constraint to",
+ "type": "array",
+ "items": {
+ "type": "string"
+ }
+ },
+ "type": {
+ "description": "Type of the constraint",
+ "type": "string",
+ "enum": ["unique"]
+ },
+ "deferrable": {
+ "description": "Deferable constraint",
+ "type": "boolean",
+ "default": false
+ },
+ "initially_deferred": {
+ "description": "Initially deferred constraint",
+ "type": "boolean",
+ "default": false
+ },
+ "nulls_not_distinct": {
+ "description": "Nulls not distinct constraint",
+ "type": "boolean",
+ "default": false
+ },
+ "index_parameters": {
+ "type": "object",
+ "additionalProperties": false,
+ "properties": {
+ "tablespace": {
+ "type": "string",
+ "default": ""
+ },
+ "storage_parameters": {
+ "type": "string",
+ "default": ""
+ },
+ "include_columns": {
+ "type": "array",
+ "items": {
+ "type": "string"
+ }
+ }
+ }
+ }
+ },
+ "required": ["name", "type"],
+ "type": "object"
+ },
"OpAddColumn": {
"additionalProperties": false,
"description": "Add column operation",
@@ -279,6 +338,13 @@
"comment": {
"description": "Postgres comment for the table",
"type": "string"
+ },
+ "constraints": {
+ "items": {
+ "$ref": "#/$defs/Constraint",
+ "description": "Constraints to add to the table"
+ },
+ "type": "array"
}
},
"required": ["columns", "name"],