Skip to content

Commit

Permalink
sql: Added CREATE SEQUENCE AS <typename> option.
Browse files Browse the repository at this point in the history
Previously, unimplementedWithIssueDetail error was thrown
when an AS option in CREATE SEQUENCE ... AS was encountered.

Now we support the AS option for creating sequences which can
take on values such as smallint/integer/bigint. Typically (i.e.
in Postgres) the AS option allows users to specify an integer
type, which dictates the min and max integer values a sequence
can take on. Before this change, the only option value we supported was
bigint/int8/int/integer, which corresponds to our default
min and max values for sequences.

NB: In postgres, `integer` corresponds to int4. In cockroach, we use
`nakedIntType` which defaults to int8 but can be configured in the
cluster settings.

Release note (sql change): Added CREATE SEQUENCE AS <typename> option.
  • Loading branch information
mokaixu committed Dec 22, 2020
1 parent f41f07c commit 361311b
Show file tree
Hide file tree
Showing 15 changed files with 898 additions and 393 deletions.
4 changes: 2 additions & 2 deletions docs/generated/sql/bnf/alter_sequence_options_stmt.bnf
Original file line number Diff line number Diff line change
@@ -1,3 +1,3 @@
alter_sequence_options_stmt ::=
'ALTER' 'SEQUENCE' sequence_name ( ( ( 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) ( ( ( 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) )* )
| 'ALTER' 'SEQUENCE' 'IF' 'EXISTS' sequence_name ( ( ( 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) ( ( ( 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) )* )
'ALTER' 'SEQUENCE' sequence_name ( ( ( 'AS' typename | 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) ( ( ( 'AS' typename | 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) )* )
| 'ALTER' 'SEQUENCE' 'IF' 'EXISTS' sequence_name ( ( ( 'AS' typename | 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) ( ( ( 'AS' typename | 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) )* )
4 changes: 2 additions & 2 deletions docs/generated/sql/bnf/create_sequence_stmt.bnf
Original file line number Diff line number Diff line change
@@ -1,3 +1,3 @@
create_sequence_stmt ::=
'CREATE' opt_temp 'SEQUENCE' sequence_name ( ( ( ( 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) ( ( ( 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) )* ) | )
| 'CREATE' opt_temp 'SEQUENCE' 'IF' 'NOT' 'EXISTS' sequence_name ( ( ( ( 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) ( ( ( 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) )* ) | )
'CREATE' opt_temp 'SEQUENCE' sequence_name ( ( ( ( 'AS' typename | 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) ( ( ( 'AS' typename | 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) )* ) | )
| 'CREATE' opt_temp 'SEQUENCE' 'IF' 'NOT' 'EXISTS' sequence_name ( ( ( ( 'AS' typename | 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) ( ( ( 'AS' typename | 'NO' 'CYCLE' | 'OWNED' 'BY' 'NONE' | 'OWNED' 'BY' column_name | 'INCREMENT' integer | 'INCREMENT' 'BY' integer | 'MINVALUE' integer | 'NO' 'MINVALUE' | 'MAXVALUE' integer | 'NO' 'MAXVALUE' | 'START' integer | 'START' 'WITH' integer | 'VIRTUAL' ) ) )* ) | )
3 changes: 2 additions & 1 deletion docs/generated/sql/bnf/stmt_block.bnf
Original file line number Diff line number Diff line change
Expand Up @@ -2502,7 +2502,8 @@ alter_index_cmd ::=
partition_by

sequence_option_elem ::=
'NO' 'CYCLE'
'AS' typename
| 'NO' 'CYCLE'
| 'OWNED' 'BY' 'NONE'
| 'OWNED' 'BY' column_path
| 'INCREMENT' signed_iconst64
Expand Down
18 changes: 9 additions & 9 deletions pkg/ccl/importccl/import_stmt_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -1502,8 +1502,8 @@ func TestImportRowLimit(t *testing.T) {
{
name: "pgdump single table with insert",
typ: "PGDUMP",
data: `CREATE TABLE t (a INT, b INT);
INSERT INTO t (a, b) VALUES (1, 2), (3, 4);
data: `CREATE TABLE t (a INT, b INT);
INSERT INTO t (a, b) VALUES (1, 2), (3, 4);
`,
with: `WITH row_limit = '1'`,
verifyQuery: `SELECT * from t`,
Expand All @@ -1526,8 +1526,8 @@ func TestImportRowLimit(t *testing.T) {
{
name: "mysqldump single table",
typ: "MYSQLDUMP",
data: `CREATE TABLE t (a INT, b INT);
INSERT INTO t (a, b) VALUES (5, 6), (7, 8);
data: `CREATE TABLE t (a INT, b INT);
INSERT INTO t (a, b) VALUES (5, 6), (7, 8);
`,
with: `WITH row_limit = '1'`,
verifyQuery: `SELECT * from t`,
Expand All @@ -1536,11 +1536,11 @@ func TestImportRowLimit(t *testing.T) {
{
name: "mysqldump multiple inserts same table",
typ: "MYSQLDUMP",
data: `CREATE TABLE t (a INT, b INT);
INSERT INTO t (a, b) VALUES (1, 2);
INSERT INTO t (a, b) VALUES (3, 4);
INSERT INTO t (a, b) VALUES (5, 6);
INSERT INTO t (a, b) VALUES (7, 8);
data: `CREATE TABLE t (a INT, b INT);
INSERT INTO t (a, b) VALUES (1, 2);
INSERT INTO t (a, b) VALUES (3, 4);
INSERT INTO t (a, b) VALUES (5, 6);
INSERT INTO t (a, b) VALUES (7, 8);
`,
with: `WITH row_limit = '2'`,
verifyQuery: `SELECT * from t`,
Expand Down
124 changes: 124 additions & 0 deletions pkg/ccl/importccl/read_import_pgdump_test.go
Original file line number Diff line number Diff line change
Expand Up @@ -9,11 +9,18 @@
package importccl

import (
"context"
"fmt"
"io"
"net/http"
"net/http/httptest"
"strings"
"testing"

"github.com/cockroachdb/cockroach/pkg/base"
"github.com/cockroachdb/cockroach/pkg/testutils"
"github.com/cockroachdb/cockroach/pkg/testutils/sqlutils"
"github.com/cockroachdb/cockroach/pkg/testutils/testcluster"
"github.com/cockroachdb/cockroach/pkg/util/leaktest"
"github.com/cockroachdb/cockroach/pkg/util/log"
)
Expand Down Expand Up @@ -149,3 +156,120 @@ COPY done;
t.Fatalf("got %s, expected %s", got, expect)
}
}

func TestImportCreateSequenceAs(t *testing.T) {
defer leaktest.AfterTest(t)()
defer log.Scope(t).Close(t)
ctx := context.Background()
baseDir, cleanup := testutils.TempDir(t)
defer cleanup()
tc := testcluster.StartTestCluster(
t, 1, base.TestClusterArgs{ServerArgs: base.TestServerArgs{ExternalIODir: baseDir}})
defer tc.Stopper().Stop(ctx)
conn := tc.Conns[0]
sqlDB := sqlutils.MakeSQLRunner(conn)

var data string
srv := httptest.NewServer(http.HandlerFunc(func(w http.ResponseWriter, r *http.Request) {
if r.Method == "GET" {
_, _ = w.Write([]byte(data))
}
}))
defer srv.Close()

tests := []struct {
name string
data string
verifyQuery string
err string
expected [][]string
}{
{
name: "as integer",
data: `
CREATE SEQUENCE public.a_seq AS integer
START WITH 2
INCREMENT BY 1
MINVALUE 0
MAXVALUE 234567
CACHE 1;`,
verifyQuery: `SHOW CREATE SEQUENCE a_seq`,
expected: [][]string{{
"a_seq", `CREATE SEQUENCE public.a_seq AS INT8 MINVALUE 0 MAXVALUE 234567 INCREMENT 1 START 2`,
}},
},
{
name: "as integer desc",
data: `
CREATE SEQUENCE public.a_seq AS integer
START WITH -20000
INCREMENT BY -1
MINVALUE -20000
MAXVALUE 0
CACHE 1;`,
verifyQuery: `SHOW CREATE SEQUENCE a_seq`,
expected: [][]string{{
"a_seq", `CREATE SEQUENCE public.a_seq AS INT8 MINVALUE -20000 MAXVALUE 0 INCREMENT -1 START -20000`,
}},
},
{
name: "as bigint",
data: `
CREATE SEQUENCE public.a_seq AS bigint
START WITH 1
INCREMENT BY 1
CACHE 1;`,
verifyQuery: `SHOW CREATE SEQUENCE a_seq`,
expected: [][]string{{
"a_seq", `CREATE SEQUENCE public.a_seq AS INT8 MINVALUE 1 MAXVALUE 9223372036854775807 INCREMENT 1 START 1`,
}},
},
{
name: "as smallint",
data: `
CREATE SEQUENCE public.a_seq AS smallint
START WITH 2
INCREMENT BY 3
CACHE 1;`,
verifyQuery: `SHOW CREATE SEQUENCE a_seq`,
expected: [][]string{{
"a_seq", `CREATE SEQUENCE public.a_seq AS INT2 MINVALUE 1 MAXVALUE 32767 INCREMENT 3 START 2`,
}},
},
{
name: `MAXINT overrides integer type default max`,
data: `
CREATE SEQUENCE public.a_seq
AS integer
START WITH 1
INCREMENT BY 1
MAXVALUE 9001
CACHE 1;`,
verifyQuery: `SHOW CREATE SEQUENCE a_seq`,
expected: [][]string{{
"a_seq", `CREATE SEQUENCE public.a_seq AS INT8 MINVALUE 1 MAXVALUE 9001 INCREMENT 1 START 1`,
}},
},
}
for _, test := range tests {

t.Run(test.name, func(t *testing.T) {
// Set up clean testing environment.
sqlDB.Exec(t, `DROP SEQUENCE IF EXISTS a_seq`)

importDumpQuery := `IMPORT PGDUMP ($1)`
data = test.data

if test.err != "" {
sqlDB.ExpectErr(t, test.err, importDumpQuery, srv.URL)
sqlDB.ExpectErr(t, `relation "a_seq" does not exist`, `DROP SEQUENCE a_seq`)

} else {
// Import PGDump and verify expected behavior.
sqlDB.Exec(t, importDumpQuery, srv.URL)
sqlDB.CheckQueryResults(t, test.verifyQuery, test.expected)
sqlDB.Exec(t, `DROP SEQUENCE a_seq`)
}
})
}
}
Loading

0 comments on commit 361311b

Please sign in to comment.