From: Peter Eisentraut Date: Sun, 2 Jan 2011 13:08:08 +0000 (+0200) Subject: Implement remaining fields of information_schema.sequences view X-Git-Tag: REL9_1_ALPHA4~533 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=39b88432968a2f4c01c20948f12bf9c8e388474d;p=postgresql Implement remaining fields of information_schema.sequences view Add new function pg_sequence_parameters that returns a sequence's start, minimum, maximum, increment, and cycle values, and use that in the view. (bug #5662; design suggestion by Tom Lane) Also slightly adjust the view's column order and permissions after review of SQL standard. --- diff --git a/doc/src/sgml/information_schema.sgml b/doc/src/sgml/information_schema.sgml index 962b85b8e4..5861595c29 100644 --- a/doc/src/sgml/information_schema.sgml +++ b/doc/src/sgml/information_schema.sgml @@ -4139,31 +4139,42 @@ ORDER BY c.ordinal_position; - maximum_value - cardinal_number - Not yet implemented + start_value + character_data + The start value of the sequence minimum_value - cardinal_number - Not yet implemented + character_data + The minimum value of the sequence + + + + maximum_value + character_data + The maximum value of the sequence increment - cardinal_number - Not yet implemented + character_data + The increment of the sequence cycle_option yes_or_no - Not yet implemented + YES if the sequence cycles, else NO + + + Note that in accordance with the SQL standard, the start, minimum, + maximum, and increment values are returned as character strings. + diff --git a/src/backend/catalog/information_schema.sql b/src/backend/catalog/information_schema.sql index 090c10c322..5b8b941770 100644 --- a/src/backend/catalog/information_schema.sql +++ b/src/backend/catalog/information_schema.sql @@ -1430,16 +1430,18 @@ CREATE VIEW sequences AS CAST(64 AS cardinal_number) AS numeric_precision, CAST(2 AS cardinal_number) AS numeric_precision_radix, CAST(0 AS cardinal_number) AS numeric_scale, - CAST(null AS cardinal_number) AS maximum_value, -- FIXME - CAST(null AS cardinal_number) AS minimum_value, -- FIXME - CAST(null AS cardinal_number) AS increment, -- FIXME - CAST(null AS yes_or_no) AS cycle_option -- FIXME + -- XXX: The following could be improved if we had LATERAL. + CAST((pg_sequence_parameters(c.oid)).start_value AS character_data) AS start_value, + CAST((pg_sequence_parameters(c.oid)).minimum_value AS character_data) AS minimum_value, + CAST((pg_sequence_parameters(c.oid)).maximum_value AS character_data) AS maximum_value, + CAST((pg_sequence_parameters(c.oid)).increment AS character_data) AS increment, + CAST(CASE WHEN (pg_sequence_parameters(c.oid)).cycle_option THEN 'YES' ELSE 'NO' END AS yes_or_no) AS cycle_option FROM pg_namespace nc, pg_class c WHERE c.relnamespace = nc.oid AND c.relkind = 'S' AND (NOT pg_is_other_temp_schema(nc.oid)) AND (pg_has_role(c.relowner, 'USAGE') - OR has_table_privilege(c.oid, 'SELECT, UPDATE') ); + OR has_sequence_privilege(c.oid, 'SELECT, UPDATE, USAGE') ); GRANT SELECT ON sequences TO PUBLIC; diff --git a/src/backend/commands/sequence.c b/src/backend/commands/sequence.c index 39d2f9a806..0ff722d6f8 100644 --- a/src/backend/commands/sequence.c +++ b/src/backend/commands/sequence.c @@ -24,6 +24,7 @@ #include "commands/defrem.h" #include "commands/sequence.h" #include "commands/tablecmds.h" +#include "funcapi.h" #include "miscadmin.h" #include "nodes/makefuncs.h" #include "storage/bufmgr.h" @@ -1420,6 +1421,56 @@ process_owned_by(Relation seqrel, List *owned_by) } +/* + * Return sequence parameters, for use by information schema + */ +Datum +pg_sequence_parameters(PG_FUNCTION_ARGS) +{ + Oid relid = PG_GETARG_OID(0); + TupleDesc tupdesc; + Datum values[5]; + bool isnull[5]; + SeqTable elm; + Relation seqrel; + Buffer buf; + Form_pg_sequence seq; + + /* open and AccessShareLock sequence */ + init_sequence(relid, &elm, &seqrel); + + if (pg_class_aclcheck(relid, GetUserId(), ACL_SELECT | ACL_UPDATE | ACL_USAGE) != ACLCHECK_OK) + ereport(ERROR, + (errcode(ERRCODE_INSUFFICIENT_PRIVILEGE), + errmsg("permission denied for sequence %s", + RelationGetRelationName(seqrel)))); + + tupdesc = CreateTemplateTupleDesc(5, false); + TupleDescInitEntry(tupdesc, (AttrNumber) 1, "start_value", INT8OID, -1, 0); + TupleDescInitEntry(tupdesc, (AttrNumber) 2, "minimum_value", INT8OID, -1, 0); + TupleDescInitEntry(tupdesc, (AttrNumber) 3, "maximum_value", INT8OID, -1, 0); + TupleDescInitEntry(tupdesc, (AttrNumber) 4, "increment", INT8OID, -1, 0); + TupleDescInitEntry(tupdesc, (AttrNumber) 5, "cycle_option", BOOLOID, -1, 0); + + BlessTupleDesc(tupdesc); + + memset(isnull, 0, sizeof(isnull)); + + seq = read_info(elm, seqrel, &buf); + + values[0] = Int64GetDatum(seq->start_value); + values[1] = Int64GetDatum(seq->min_value); + values[2] = Int64GetDatum(seq->max_value); + values[3] = Int64GetDatum(seq->increment_by); + values[4] = BoolGetDatum(seq->is_cycled); + + UnlockReleaseBuffer(buf); + relation_close(seqrel, NoLock); + + return HeapTupleGetDatum(heap_form_tuple(tupdesc, values, isnull)); +} + + void seq_redo(XLogRecPtr lsn, XLogRecord *record) { diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h index 8e41305691..5d57d1127f 100644 --- a/src/include/catalog/catversion.h +++ b/src/include/catalog/catversion.h @@ -53,6 +53,6 @@ */ /* yyyymmddN */ -#define CATALOG_VERSION_NO 201101011 +#define CATALOG_VERSION_NO 201101021 #endif diff --git a/src/include/catalog/pg_proc.h b/src/include/catalog/pg_proc.h index 386c34a59a..080a7fde6f 100644 --- a/src/include/catalog/pg_proc.h +++ b/src/include/catalog/pg_proc.h @@ -2120,6 +2120,8 @@ DATA(insert OID = 1576 ( setval PGNSP PGUID 12 1 0 0 f f f t f v 2 0 20 "2205 DESCR("set sequence value"); DATA(insert OID = 1765 ( setval PGNSP PGUID 12 1 0 0 f f f t f v 3 0 20 "2205 20 16" _null_ _null_ _null_ _null_ setval3_oid _null_ _null_ _null_ )); DESCR("set sequence value and iscalled status"); +DATA(insert OID = 3078 ( pg_sequence_parameters PGNSP PGUID 12 1 0 0 f f f t f s 1 0 2249 "26" "{23,20,20,20,20,16}" "{i,o,o,o,o,o}" "{sequence_oid,start_value,minimum_value,maximum_value,increment,cycle_option}" _null_ pg_sequence_parameters _null_ _null_ _null_)); +DESCR("sequence parameters, for use by information schema"); DATA(insert OID = 1579 ( varbit_in PGNSP PGUID 12 1 0 0 f f f t f i 3 0 1562 "2275 26 23" _null_ _null_ _null_ _null_ varbit_in _null_ _null_ _null_ )); DESCR("I/O"); diff --git a/src/include/commands/sequence.h b/src/include/commands/sequence.h index 932e20351c..3f3ba52948 100644 --- a/src/include/commands/sequence.h +++ b/src/include/commands/sequence.h @@ -69,6 +69,8 @@ extern Datum setval_oid(PG_FUNCTION_ARGS); extern Datum setval3_oid(PG_FUNCTION_ARGS); extern Datum lastval(PG_FUNCTION_ARGS); +extern Datum pg_sequence_parameters(PG_FUNCTION_ARGS); + extern void DefineSequence(CreateSeqStmt *stmt); extern void AlterSequence(AlterSeqStmt *stmt); extern void ResetSequence(Oid seq_relid); diff --git a/src/test/regress/expected/sequence.out b/src/test/regress/expected/sequence.out index 19f8f1308d..13e1565272 100644 --- a/src/test/regress/expected/sequence.out +++ b/src/test/regress/expected/sequence.out @@ -220,6 +220,13 @@ SELECT nextval('sequence_test2'); 5 (1 row) +-- Information schema +SELECT * FROM information_schema.sequences WHERE sequence_name IN ('sequence_test2'); + sequence_catalog | sequence_schema | sequence_name | data_type | numeric_precision | numeric_precision_radix | numeric_scale | start_value | minimum_value | maximum_value | increment | cycle_option +------------------+-----------------+----------------+-----------+-------------------+-------------------------+---------------+-------------+---------------+---------------+-----------+-------------- + regression | public | sequence_test2 | bigint | 64 | 2 | 0 | 32 | 5 | 36 | 4 | YES +(1 row) + -- Test comments COMMENT ON SEQUENCE asdf IS 'won''t work'; ERROR: relation "asdf" does not exist diff --git a/src/test/regress/sql/sequence.sql b/src/test/regress/sql/sequence.sql index 433e992994..29ea69123a 100644 --- a/src/test/regress/sql/sequence.sql +++ b/src/test/regress/sql/sequence.sql @@ -85,6 +85,9 @@ SELECT nextval('sequence_test2'); SELECT nextval('sequence_test2'); SELECT nextval('sequence_test2'); +-- Information schema +SELECT * FROM information_schema.sequences WHERE sequence_name IN ('sequence_test2'); + -- Test comments COMMENT ON SEQUENCE asdf IS 'won''t work'; COMMENT ON SEQUENCE sequence_test2 IS 'will work';