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.
This commit is contained in:
parent
e657b55e66
commit
39b8843296
@ -4139,31 +4139,42 @@ ORDER BY c.ordinal_position;
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>maximum_value</literal></entry>
|
||||
<entry><type>cardinal_number</type></entry>
|
||||
<entry>Not yet implemented</entry>
|
||||
<entry><literal>start_value</literal></entry>
|
||||
<entry><type>character_data</type></entry>
|
||||
<entry>The start value of the sequence</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>minimum_value</literal></entry>
|
||||
<entry><type>cardinal_number</type></entry>
|
||||
<entry>Not yet implemented</entry>
|
||||
<entry><type>character_data</type></entry>
|
||||
<entry>The minimum value of the sequence</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>maximum_value</literal></entry>
|
||||
<entry><type>character_data</type></entry>
|
||||
<entry>The maximum value of the sequence</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>increment</literal></entry>
|
||||
<entry><type>cardinal_number</type></entry>
|
||||
<entry>Not yet implemented</entry>
|
||||
<entry><type>character_data</type></entry>
|
||||
<entry>The increment of the sequence</entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry><literal>cycle_option</literal></entry>
|
||||
<entry><type>yes_or_no</type></entry>
|
||||
<entry>Not yet implemented</entry>
|
||||
<entry><literal>YES</literal> if the sequence cycles, else <literal>NO</literal></entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
<para>
|
||||
Note that in accordance with the SQL standard, the start, minimum,
|
||||
maximum, and increment values are returned as character strings.
|
||||
</para>
|
||||
</sect1>
|
||||
|
||||
<sect1 id="infoschema-sql-features">
|
||||
|
@ -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;
|
||||
|
||||
|
@ -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)
|
||||
{
|
||||
|
@ -53,6 +53,6 @@
|
||||
*/
|
||||
|
||||
/* yyyymmddN */
|
||||
#define CATALOG_VERSION_NO 201101011
|
||||
#define CATALOG_VERSION_NO 201101021
|
||||
|
||||
#endif
|
||||
|
@ -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");
|
||||
|
@ -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);
|
||||
|
@ -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
|
||||
|
@ -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';
|
||||
|
Loading…
Reference in New Issue
Block a user