--- --- test creation of SERIAL column --- CREATE TABLE serialTest (f1 text, f2 serial); INSERT INTO serialTest VALUES ('foo'); INSERT INTO serialTest VALUES ('bar'); INSERT INTO serialTest VALUES ('force', 100); INSERT INTO serialTest VALUES ('wrong', NULL); SELECT * FROM serialTest; -- test smallserial / bigserial CREATE TABLE serialTest2 (f1 text, f2 serial, f3 smallserial, f4 serial2, f5 bigserial, f6 serial8); INSERT INTO serialTest2 (f1) VALUES ('test_defaults'); INSERT INTO serialTest2 (f1, f2, f3, f4, f5, f6) VALUES ('test_max_vals', 2147483647, 32767, 32767, 9223372036854775807, 9223372036854775807), ('test_min_vals', -2147483648, -32768, -32768, -9223372036854775808, -9223372036854775808); -- All these INSERTs should fail: INSERT INTO serialTest2 (f1, f3) VALUES ('bogus', -32769); INSERT INTO serialTest2 (f1, f4) VALUES ('bogus', -32769); INSERT INTO serialTest2 (f1, f3) VALUES ('bogus', 32768); INSERT INTO serialTest2 (f1, f4) VALUES ('bogus', 32768); INSERT INTO serialTest2 (f1, f5) VALUES ('bogus', -9223372036854775809); INSERT INTO serialTest2 (f1, f6) VALUES ('bogus', -9223372036854775809); INSERT INTO serialTest2 (f1, f5) VALUES ('bogus', 9223372036854775808); INSERT INTO serialTest2 (f1, f6) VALUES ('bogus', 9223372036854775808); SELECT * FROM serialTest2 ORDER BY f2 ASC; SELECT nextval('serialTest2_f2_seq'); SELECT nextval('serialTest2_f3_seq'); SELECT nextval('serialTest2_f4_seq'); SELECT nextval('serialTest2_f5_seq'); SELECT nextval('serialTest2_f6_seq'); -- basic sequence operations using both text and oid references CREATE SEQUENCE sequence_test; CREATE SEQUENCE IF NOT EXISTS sequence_test; SELECT nextval('sequence_test'::text); SELECT nextval('sequence_test'::regclass); SELECT currval('sequence_test'::text); SELECT currval('sequence_test'::regclass); SELECT setval('sequence_test'::text, 32); SELECT nextval('sequence_test'::regclass); SELECT setval('sequence_test'::text, 99, false); SELECT nextval('sequence_test'::regclass); SELECT setval('sequence_test'::regclass, 32); SELECT nextval('sequence_test'::text); SELECT setval('sequence_test'::regclass, 99, false); SELECT nextval('sequence_test'::text); DISCARD SEQUENCES; SELECT currval('sequence_test'::regclass); DROP SEQUENCE sequence_test; -- renaming sequences CREATE SEQUENCE foo_seq; ALTER TABLE foo_seq RENAME TO foo_seq_new; SELECT * FROM foo_seq_new; SELECT nextval('foo_seq_new'); SELECT nextval('foo_seq_new'); SELECT * FROM foo_seq_new; DROP SEQUENCE foo_seq_new; -- renaming serial sequences ALTER TABLE serialtest_f2_seq RENAME TO serialtest_f2_foo; INSERT INTO serialTest VALUES ('more'); SELECT * FROM serialTest; -- -- Check dependencies of serial and ordinary sequences -- CREATE TEMP SEQUENCE myseq2; CREATE TEMP SEQUENCE myseq3; CREATE TEMP TABLE t1 ( f1 serial, f2 int DEFAULT nextval('myseq2'), f3 int DEFAULT nextval('myseq3'::text) ); -- Both drops should fail, but with different error messages: DROP SEQUENCE t1_f1_seq; DROP SEQUENCE myseq2; -- This however will work: DROP SEQUENCE myseq3; DROP TABLE t1; -- Fails because no longer existent: DROP SEQUENCE t1_f1_seq; -- Now OK: DROP SEQUENCE myseq2; -- -- Alter sequence -- ALTER SEQUENCE IF EXISTS sequence_test2 RESTART WITH 24 INCREMENT BY 4 MAXVALUE 36 MINVALUE 5 CYCLE; CREATE SEQUENCE sequence_test2 START WITH 32; SELECT nextval('sequence_test2'); ALTER SEQUENCE sequence_test2 RESTART WITH 24 INCREMENT BY 4 MAXVALUE 36 MINVALUE 5 CYCLE; SELECT nextval('sequence_test2'); SELECT nextval('sequence_test2'); SELECT nextval('sequence_test2'); SELECT nextval('sequence_test2'); SELECT nextval('sequence_test2'); ALTER SEQUENCE sequence_test2 RESTART; SELECT nextval('sequence_test2'); SELECT nextval('sequence_test2'); SELECT nextval('sequence_test2'); CREATE SEQUENCE sequence_test3; -- not read from, to test is_called -- Information schema SELECT * FROM information_schema.sequences WHERE sequence_name IN ('sequence_test2', 'sequence_test3', 'serialtest2_f2_seq', 'serialtest2_f3_seq', 'serialtest2_f4_seq', 'serialtest2_f5_seq', 'serialtest2_f6_seq') ORDER BY sequence_name ASC; SELECT schemaname, sequencename, start_value, min_value, max_value, increment_by, cycle, cache_size, last_value FROM pg_sequences WHERE sequencename IN ('sequence_test2', 'sequence_test3', 'serialtest2_f2_seq', 'serialtest2_f3_seq', 'serialtest2_f4_seq', 'serialtest2_f5_seq', 'serialtest2_f6_seq') ORDER BY sequencename ASC; -- Test comments COMMENT ON SEQUENCE asdf IS 'won''t work'; COMMENT ON SEQUENCE sequence_test2 IS 'will work'; COMMENT ON SEQUENCE sequence_test2 IS NULL; -- Test lastval() CREATE SEQUENCE seq; SELECT nextval('seq'); SELECT lastval(); SELECT setval('seq', 99); SELECT lastval(); DISCARD SEQUENCES; SELECT lastval(); CREATE SEQUENCE seq2; SELECT nextval('seq2'); SELECT lastval(); DROP SEQUENCE seq2; -- should fail SELECT lastval(); CREATE USER regress_seq_user; -- privileges tests -- nextval BEGIN; SET LOCAL SESSION AUTHORIZATION regress_seq_user; CREATE SEQUENCE seq3; REVOKE ALL ON seq3 FROM regress_seq_user; GRANT SELECT ON seq3 TO regress_seq_user; SELECT nextval('seq3'); ROLLBACK; BEGIN; SET LOCAL SESSION AUTHORIZATION regress_seq_user; CREATE SEQUENCE seq3; REVOKE ALL ON seq3 FROM regress_seq_user; GRANT UPDATE ON seq3 TO regress_seq_user; SELECT nextval('seq3'); ROLLBACK; BEGIN; SET LOCAL SESSION AUTHORIZATION regress_seq_user; CREATE SEQUENCE seq3; REVOKE ALL ON seq3 FROM regress_seq_user; GRANT USAGE ON seq3 TO regress_seq_user; SELECT nextval('seq3'); ROLLBACK; -- currval BEGIN; SET LOCAL SESSION AUTHORIZATION regress_seq_user; CREATE SEQUENCE seq3; SELECT nextval('seq3'); REVOKE ALL ON seq3 FROM regress_seq_user; GRANT SELECT ON seq3 TO regress_seq_user; SELECT currval('seq3'); ROLLBACK; BEGIN; SET LOCAL SESSION AUTHORIZATION regress_seq_user; CREATE SEQUENCE seq3; SELECT nextval('seq3'); REVOKE ALL ON seq3 FROM regress_seq_user; GRANT UPDATE ON seq3 TO regress_seq_user; SELECT currval('seq3'); ROLLBACK; BEGIN; SET LOCAL SESSION AUTHORIZATION regress_seq_user; CREATE SEQUENCE seq3; SELECT nextval('seq3'); REVOKE ALL ON seq3 FROM regress_seq_user; GRANT USAGE ON seq3 TO regress_seq_user; SELECT currval('seq3'); ROLLBACK; -- lastval BEGIN; SET LOCAL SESSION AUTHORIZATION regress_seq_user; CREATE SEQUENCE seq3; SELECT nextval('seq3'); REVOKE ALL ON seq3 FROM regress_seq_user; GRANT SELECT ON seq3 TO regress_seq_user; SELECT lastval(); ROLLBACK; BEGIN; SET LOCAL SESSION AUTHORIZATION regress_seq_user; CREATE SEQUENCE seq3; SELECT nextval('seq3'); REVOKE ALL ON seq3 FROM regress_seq_user; GRANT UPDATE ON seq3 TO regress_seq_user; SELECT lastval(); ROLLBACK; BEGIN; SET LOCAL SESSION AUTHORIZATION regress_seq_user; CREATE SEQUENCE seq3; SELECT nextval('seq3'); REVOKE ALL ON seq3 FROM regress_seq_user; GRANT USAGE ON seq3 TO regress_seq_user; SELECT lastval(); ROLLBACK; -- Sequences should get wiped out as well: DROP TABLE serialTest, serialTest2; -- Make sure sequences are gone: SELECT * FROM information_schema.sequences WHERE sequence_name IN ('sequence_test2', 'serialtest2_f2_seq', 'serialtest2_f3_seq', 'serialtest2_f4_seq', 'serialtest2_f5_seq', 'serialtest2_f6_seq') ORDER BY sequence_name ASC; DROP USER regress_seq_user; DROP SEQUENCE seq;