Information Schema

information_schema is a special schema that contains virtual tables which are read-only and can be queried to get information about the state of the cluster.

Table of Contents

Access

When the user management is enabled, accessing the information_schema is open to all users and it does not require any privileges.

However, being able to query information_schema tables will not allow the user to retrieve all the rows in the table, as it can contain information related to tables over which the connected user does not have any privileges. The only rows that will be returned will be the ones the user is allowed to access.

For example, if the user john has any privilege on the doc.books table but no privilege at all on doc.locations, when john issues a SELECT * FROM information_schema.tables statement, the tables information related to the doc.locations table will not be returned.

Virtual Tables

tables

The information_schema.tables virtual table can be queried to get a list of all available tables and views and their settings, such as number of shards or number of replicas.

  1. cr> SELECT table_schema, table_name, table_type, number_of_shards, number_of_replicas
  2. ... FROM information_schema.tables
  3. ... ORDER BY table_schema ASC, table_name ASC;
  4. +--------------------+-------------------------+------------+------------------+--------------------+
  5. | table_schema | table_name | table_type | number_of_shards | number_of_replicas |
  6. +--------------------+-------------------------+------------+------------------+--------------------+
  7. | doc | galaxies | VIEW | NULL | NULL |
  8. | doc | locations | BASE TABLE | 2 | 0 |
  9. | doc | partitioned_table | BASE TABLE | 4 | 0-1 |
  10. | doc | quotes | BASE TABLE | 2 | 0 |
  11. | information_schema | columns | BASE TABLE | NULL | NULL |
  12. | information_schema | ingestion_rules | BASE TABLE | NULL | NULL |
  13. | information_schema | key_column_usage | BASE TABLE | NULL | NULL |
  14. | information_schema | referential_constraints | BASE TABLE | NULL | NULL |
  15. | information_schema | routines | BASE TABLE | NULL | NULL |
  16. | information_schema | schemata | BASE TABLE | NULL | NULL |
  17. | information_schema | sql_features | BASE TABLE | NULL | NULL |
  18. | information_schema | table_constraints | BASE TABLE | NULL | NULL |
  19. | information_schema | table_partitions | BASE TABLE | NULL | NULL |
  20. | information_schema | tables | BASE TABLE | NULL | NULL |
  21. | information_schema | views | BASE TABLE | NULL | NULL |
  22. | pg_catalog | pg_attrdef | BASE TABLE | NULL | NULL |
  23. | pg_catalog | pg_attribute | BASE TABLE | NULL | NULL |
  24. | pg_catalog | pg_class | BASE TABLE | NULL | NULL |
  25. | pg_catalog | pg_constraint | BASE TABLE | NULL | NULL |
  26. | pg_catalog | pg_database | BASE TABLE | NULL | NULL |
  27. | pg_catalog | pg_description | BASE TABLE | NULL | NULL |
  28. | pg_catalog | pg_index | BASE TABLE | NULL | NULL |
  29. | pg_catalog | pg_namespace | BASE TABLE | NULL | NULL |
  30. | pg_catalog | pg_type | BASE TABLE | NULL | NULL |
  31. | sys | allocations | BASE TABLE | NULL | NULL |
  32. | sys | checks | BASE TABLE | NULL | NULL |
  33. | sys | cluster | BASE TABLE | NULL | NULL |
  34. | sys | health | BASE TABLE | NULL | NULL |
  35. | sys | jobs | BASE TABLE | NULL | NULL |
  36. | sys | jobs_log | BASE TABLE | NULL | NULL |
  37. | sys | jobs_metrics | BASE TABLE | NULL | NULL |
  38. | sys | node_checks | BASE TABLE | NULL | NULL |
  39. | sys | nodes | BASE TABLE | NULL | NULL |
  40. | sys | operations | BASE TABLE | NULL | NULL |
  41. | sys | operations_log | BASE TABLE | NULL | NULL |
  42. | sys | privileges | BASE TABLE | NULL | NULL |
  43. | sys | repositories | BASE TABLE | NULL | NULL |
  44. | sys | shards | BASE TABLE | NULL | NULL |
  45. | sys | snapshots | BASE TABLE | NULL | NULL |
  46. | sys | summits | BASE TABLE | NULL | NULL |
  47. | sys | users | BASE TABLE | NULL | NULL |
  48. +--------------------+-------------------------+------------+------------------+--------------------+
  49. SELECT 41 rows in set (... sec)

The table also contains additional information such as specified routing (Sharding) and partitioned by (Partitioned Tables) columns:

  1. cr> SELECT table_name, clustered_by, partitioned_by
  2. ... FROM information_schema.tables
  3. ... WHERE table_schema = 'doc'
  4. ... ORDER BY table_schema ASC, table_name ASC;
  5. +-------------------+--------------+----------------+
  6. | table_name | clustered_by | partitioned_by |
  7. +-------------------+--------------+----------------+
  8. | galaxies | NULL | NULL |
  9. | locations | id | NULL |
  10. | partitioned_table | _id | ["date"] |
  11. | quotes | id | NULL |
  12. +-------------------+--------------+----------------+
  13. SELECT 4 rows in set (... sec)

Schema

NameDescriptionData Type
blobs_pathThe data path of the blob tableString
closedThe state of the tableBoolean
clustered_byThe routing column used to cluster the tableString
column_policyDefines whether the table uses a STRICT or a DYNAMIC Column PolicyString
number_of_replicasThe number of replicas the table currently hasInteger
number_of_shardsThe number of shards the table is currently distributed acrossInteger
partitioned_byThe column used to partition the tableString
reference_generationSpecifies how values in the self-referencing column are generatedString
routing_hash_functionThe name of the hash function used for internal routingString
self_referencing_column_nameThe name of the column that uniquely identifies each row (always _id)String
settingsWITHObject
table_catalogRefers to the table_schemaString
table_nameThe name of the tableString
table_schemaThe name of the schema the table belongs toString
table_typeThe type of the table (BASE TABLE for tables, VIEW for views)String
versionA collection of version numbers relevent to the tableObject

settings

Table settings specify configuration parameters for tables. Some settings can be set during Cluster runtime and others are only applied on cluster restart.

This list of table settings in WITH shows detailed information of each parameter.

Table parameters can be applied with CREATE TABLE on creation of a table. With ALTER TABLE they can be set on already existing tables.

The following statement creates a new table and sets the refresh interval of shards to 500 ms and sets the shard allocation for primary shards only:

  1. cr> create table parameterized_table (id int, content string)
  2. ... with ("refresh_interval"=500, "routing.allocation.enable"='primaries');
  3. CREATE OK, 1 row affected (... sec)

The settings can be verified by querying information_schema.tables:

  1. cr> select settings['routing']['allocation']['enable'] as alloc_enable,
  2. ... settings['refresh_interval'] as refresh_interval
  3. ... from information_schema.tables
  4. ... where table_name='parameterized_table';
  5. +--------------+------------------+
  6. | alloc_enable | refresh_interval |
  7. +--------------+------------------+
  8. | primaries | 500 |
  9. +--------------+------------------+
  10. SELECT 1 row in set (... sec)

On existing tables this needs to be done with ALTER TABLE statement:

  1. cr> alter table parameterized_table
  2. ... set ("routing.allocation.enable"='none');
  3. ALTER OK, -1 rows affected (... sec)

views

The table information_schema.views contains the name, definition and options of all available views.

  1. cr> SELECT table_schema, table_name, view_definition
  2. ... FROM information_schema.views
  3. ... ORDER BY table_schema ASC, table_name ASC;
  4. +--------------+------------+-------------------------+
  5. | table_schema | table_name | view_definition |
  6. +--------------+------------+-------------------------+
  7. | doc | galaxies | SELECT |
  8. | | | "id" |
  9. | | | , "name" |
  10. | | | , "description" |
  11. | | | FROM "locations" |
  12. | | | WHERE "kind" = 'Galaxy' |
  13. +--------------+------------+-------------------------+
  14. SELECT 1 row in set (... sec)

Schema

NameDescriptionData Type
table_catalogThe catalog of the table of the view (refers to table_schema)String
table_schemaThe schema of the table of the viewString
table_nameThe name of the table of the viewString
view_definitionThe SELECT statement that defines the viewString
check_optionNot applicable for CrateDB, always return NONEString
is_updatableWhether the view is updatable. Not applicable for CrateDB, always returns FALSEBoolean
ownerThe user that created the viewString

Note

If you drop the table of a view, the view will still exist and show up in the information_schema.tables and information_schema.views tables.

columns

This table can be queried to get a list of all available columns of all tables and views and their definition like data type and ordinal position inside the table:

  1. cr> select table_name, column_name, ordinal_position as pos, data_type
  2. ... from information_schema.columns
  3. ... where table_schema = 'doc' and table_name not like 'my_table%'
  4. ... order by table_name asc, column_name asc;
  5. +-------------------+--------------------------------+------+--------------+
  6. | table_name | column_name | pos | data_type |
  7. +-------------------+--------------------------------+------+--------------+
  8. | locations | date | 1 | timestamp |
  9. | locations | description | 2 | string |
  10. | locations | id | 3 | string |
  11. | locations | information | 4 | object_array |
  12. | locations | information['evolution_level'] | NULL | short |
  13. | locations | information['population'] | NULL | long |
  14. | locations | kind | 5 | string |
  15. | locations | name | 6 | string |
  16. | locations | position | 7 | integer |
  17. | locations | race | 8 | object |
  18. | locations | race['description'] | NULL | string |
  19. | locations | race['interests'] | NULL | string_array |
  20. | locations | race['name'] | NULL | string |
  21. | partitioned_table | date | 1 | timestamp |
  22. | partitioned_table | id | 2 | long |
  23. | partitioned_table | title | 3 | string |
  24. | quotes | id | 1 | integer |
  25. | quotes | quote | 2 | string |
  26. +-------------------+--------------------------------+------+--------------+
  27. SELECT 18 rows in set (... sec)

You can even query this tables’ own columns (attention: this might lead to infinite recursion of your mind, beware!):

  1. cr> select column_name, data_type, ordinal_position
  2. ... from information_schema.columns
  3. ... where table_schema = 'information_schema'
  4. ... and table_name = 'columns' order by ordinal_position asc;
  5. +---------------------------+-----------+------------------+
  6. | column_name | data_type | ordinal_position |
  7. +---------------------------+-----------+------------------+
  8. | character_maximum_length | integer | 1 |
  9. | character_octet_length | integer | 2 |
  10. | character_set_catalog | string | 3 |
  11. | character_set_name | string | 4 |
  12. | character_set_schema | string | 5 |
  13. | check_action | integer | 6 |
  14. | check_references | string | 7 |
  15. | collation_catalog | string | 8 |
  16. | collation_name | string | 9 |
  17. | collation_schema | string | 10 |
  18. | column_default | string | 11 |
  19. | column_name | string | 12 |
  20. | data_type | string | 13 |
  21. | datetime_precision | integer | 14 |
  22. | domain_catalog | string | 15 |
  23. | domain_name | string | 16 |
  24. | domain_schema | string | 17 |
  25. | generation_expression | string | 18 |
  26. | interval_precision | integer | 19 |
  27. | interval_type | string | 20 |
  28. | is_generated | boolean | 21 |
  29. | is_nullable | boolean | 22 |
  30. | numeric_precision | integer | 23 |
  31. | numeric_precision_radix | integer | 24 |
  32. | numeric_scale | integer | 25 |
  33. | ordinal_position | short | 26 |
  34. | table_catalog | string | 27 |
  35. | table_name | string | 28 |
  36. | table_schema | string | 29 |
  37. | user_defined_type_catalog | string | 30 |
  38. | user_defined_type_name | string | 31 |
  39. | user_defined_type_schema | string | 32 |
  40. +---------------------------+-----------+------------------+
  41. SELECT 32 rows in set (... sec)

Note

Columns are always sorted alphabetically in ascending order regardless of the order they were defined on table creation. Thus the ordinal_position reflects the alphabetical position.

Schema

NameDescriptionData Type
table_catalogRefers to the table_schemaString
table_schemaSchema name containing the tableString
table_nameTable NameString
column_nameColumn Name For fields in object columns this is not an identifier but a path and therefore must not be double quoted when programmatically obtained.String
ordinal_positionThe position of the column within the tableInteger
is_nullableWhether the column is nullableBoolean
data_type

The data type of the column

For further information see Data Types

String
column_defaultNot implemented (always returns NULL)String
character_maximum_length

Not implemented (always returns NULL)

Please refer to string type

Integer
character_octet_length

Not implemented (always returns NULL)

Please refer to string type

Integer
numeric_precisionIndicates the number of significant digits for a numeric data_type. For all other data types this column is NULL.Integer
numeric_precision_radixIndicates in which base the value in the column numeric_precision for a numeric data_type is exposed. This can either be 2 (binary) or 10 (decimal). For all other data types this column is NULL.Integer
numeric_scaleNot implemented (always returns NULL)Integer
datetime_precisionContains the fractional seconds precision for a timestamp data_type. For all other data types this column is null.Integer
interval_typeNot implemented (always returns NULL)String
interval_precisionNot implemented (always returns NULL)Integer
character_set_catalogNot implemented (always returns NULL)String
character_set_schemaNot implemented (always returns NULL)String
character_set_nameNot implemented (always returns NULL)String
collation_catalogNot implemented (always returns NULL)String
collation_schemaNot implemented (always returns NULL)String
collation_nameNot implemented (always returns NULL)String
domain_catalogNot implemented (always returns NULL)String
domain_schemaNot implemented (always returns NULL)String
domain_nameNot implemented (always returns NULL)String
user_defined_type_catalogNot implemented (always returns NULL)String
user_defined_type_schemaNot implemented (always returns NULL)String
user_defined_type_nameNot implemented (always returns NULL)String
check_referencesNot implemented (always returns NULL)String
check_actionNot implemented (always returns NULL)Integer
generation_expressionThe expression used to generate ad column. If the column is not generated NULL is returned.String
is_generatedReturns true or false wether the column is generated or notBoolean

table_constraints

This table can be queried to get a list of all defined table constraints, their type, name and which table they are defined in.

Note

Currently only PRIMARY_KEY constraints are supported.

  1. cr> select table_schema, table_name, constraint_name, constraint_type as type
  2. ... from information_schema.table_constraints
  3. ... where table_name = 'tables'
  4. ... or table_name = 'quotes'
  5. ... or table_name = 'documents'
  6. ... or table_name = 'tbl'
  7. ... order by table_schema desc, table_name asc limit 10;
  8. +--------------------+------------+-...------------------+-------------+
  9. | table_schema | table_name | constraint_name | type |
  10. +--------------------+------------+-...------------------+-------------+
  11. | information_schema | tables | tables_pk | PRIMARY KEY |
  12. | doc | quotes | quotes_pk | PRIMARY KEY |
  13. | doc | tbl | doc_tbl_col_not_null | CHECK |
  14. +--------------------+------------+-...------------------+-------------+
  15. SELECT 3 rows in set (... sec)

key_column_usage

This table may be queried to retrieve primary key information from all user tables:

  1. cr> select constraint_name, table_name, column_name, ordinal_position
  2. ... from information_schema.key_column_usage
  3. ... where table_name = 'students'
  4. +-----------------+------------+-------------+------------------+
  5. | constraint_name | table_name | column_name | ordinal_position |
  6. +-----------------+------------+-------------+------------------+
  7. | students_pk | students | id | 1 |
  8. | students_pk | students | department | 2 |
  9. +-----------------+------------+-------------+------------------+
  10. SELECT 2 rows in set (... sec)

Schema

NameDescriptionData Type
constraint_catalogRefers to table_catalogString
constraint_schemaRefers to table_schemaString
constraint_nameName of the constraintString
table_catalogRefers to table_schemaString
table_schemaName of the schema that contains the table that contains the constraintString
table_nameName of the table that contains the constraintString
column_nameName of the column that contains the constraintString
ordinal_positionPosition of the column within the contraint (starts with 1)Integer

table_partitions

This table can be queried to get information about all partitioned tables, Each partition of a table is represented as one row. The row contains the information table name, schema name, partition ident, and the values of the partition. values is a key-value object with the ‘partitioned by column’ as key(s) and the corresponding value as value(s).

For further information see Partitioned Tables.

  1. cr> insert into a_partitioned_table (id, content) values (1, 'content_a');
  2. INSERT OK, 1 row affected (... sec)
  1. cr> alter table a_partitioned_table set (number_of_shards=5);
  2. ALTER OK, -1 rows affected (... sec)
  1. cr> insert into a_partitioned_table (id, content) values (2, 'content_b');
  2. INSERT OK, 1 row affected (... sec)

The following example shows a table where the column ‘content’ of table ‘a_partitioned_table’ has been used to partition the table. The table has two partitions. The partitions are introduced when data is inserted where ‘content’ is ‘content_a’, and ‘content_b’.:

  1. cr> select table_name, schema_name as schema, partition_ident, "values"
  2. ... from information_schema.table_partitions
  3. ... order by table_name, partition_ident;
  4. +---------------------+--------+--------------------+--------------------------+
  5. | table_name | schema | partition_ident | values |
  6. +---------------------+--------+--------------------+--------------------------+
  7. | a_partitioned_table | doc | 04566rreehimst2vc4 | {"content": "content_a"} |
  8. | a_partitioned_table | doc | 04566rreehimst2vc8 | {"content": "content_b"} |
  9. +---------------------+--------+--------------------+--------------------------+
  10. SELECT 2 rows in set (... sec)

The second partition has been created after the number of shards for future partitions have been changed on the partitioned table, so they show 5 instead of 4:

  1. cr> select table_name, partition_ident,
  2. ... number_of_shards, number_of_replicas
  3. ... from information_schema.table_partitions
  4. ... order by table_name, partition_ident;
  5. +---------------------+--------------------+------------------+--------------------+
  6. | table_name | partition_ident | number_of_shards | number_of_replicas |
  7. +---------------------+--------------------+------------------+--------------------+
  8. | a_partitioned_table | 04566rreehimst2vc4 | 4 | 0-1 |
  9. | a_partitioned_table | 04566rreehimst2vc8 | 5 | 0-1 |
  10. +---------------------+--------------------+------------------+--------------------+
  11. SELECT 2 rows in set (... sec)

routines

The routines table contains tokenizers, token-filters, char-filters, custom analyzers created by CREATE ANALYZER statements (see Create a Custom Analyzer), and functions created by CREATE FUNCTION statements:

  1. cr> select routine_name, routine_type
  2. ... from information_schema.routines
  3. ... group by routine_name, routine_type
  4. ... order by routine_name asc limit 5;
  5. +----------------------+--------------+
  6. | routine_name | routine_type |
  7. +----------------------+--------------+
  8. | PathHierarchy | TOKENIZER |
  9. | apostrophe | TOKEN_FILTER |
  10. | arabic | ANALYZER |
  11. | arabic_normalization | TOKEN_FILTER |
  12. | arabic_stem | TOKEN_FILTER |
  13. +----------------------+--------------+
  14. SELECT 5 rows in set (... sec)

For example you can use this table to list existing tokenizers like this:

  1. cr> select routine_name
  2. ... from information_schema.routines
  3. ... where routine_type='TOKENIZER'
  4. ... order by routine_name asc limit 10;
  5. +---------------+
  6. | routine_name |
  7. +---------------+
  8. | PathHierarchy |
  9. | char_group |
  10. | classic |
  11. | edgeNGram |
  12. | edge_ngram |
  13. | keyword |
  14. | letter |
  15. | lowercase |
  16. | nGram |
  17. | ngram |
  18. +---------------+
  19. SELECT 10 rows in set (... sec)

Or get an overview of how many routines and routine types are available:

  1. cr> select count(*), routine_type
  2. ... from information_schema.routines
  3. ... group by routine_type
  4. ... order by routine_type;
  5. +----------+--------------+
  6. | count(*) | routine_type |
  7. +----------+--------------+
  8. | 45 | ANALYZER |
  9. | 3 | CHAR_FILTER |
  10. | 18 | TOKENIZER |
  11. | 65 | TOKEN_FILTER |
  12. +----------+--------------+
  13. SELECT 4 rows in set (... sec)

Schema

NameData Type
routine_nameString
routine_typeString
routine_bodyString
routine_schemaString
data_typeString
is_deterministicBoolean
routine_definitionString
specific_nameString
routine_name:Name of the routine (might be duplicated in case of overloading)
routine_type:Type of the routine. Can be FUNCTION, ANALYZER, CHAR_FILTER, TOKEN_FILTER or TOKEN_FILTER.
routine_schema:The schema where the routine was defined. If it doesn’t apply, then NULL.
routine_body:The language used for the routine implementation. If it doesn’t apply, then NULL.
data_type:The return type of the function. If it doesn’t apply, then NULL.
is_deterministic:If the routine is deterministic then True, else False (NULL if it doesn’t apply).
routine_definition:The function definition (NULL if it doesn’t apply).
specific_name:Used to uniquely identify the function in a schema, even if the function is overloaded. Currently the specific name contains the types of the function arguments. As the format might change in the future, it should be only used to compare it to other instances of specific_name.

schemata

The schemata table lists all existing schemas. These schemas are always available: blob, doc, information_schema and sys:

  1. cr> select schema_name from information_schema.schemata order by schema_name;
  2. +--------------------+
  3. | schema_name |
  4. +--------------------+
  5. | blob |
  6. | doc |
  7. | information_schema |
  8. | pg_catalog |
  9. | sys |
  10. +--------------------+
  11. SELECT 5 rows in set (... sec)

sql_features

The sql_features table outlines supported and unsupported SQL features of CrateDB based to the current SQL standard (see SQL Standard Compliance):

  1. cr> select feature_name, is_supported, sub_feature_id, sub_feature_name
  2. ... from information_schema.sql_features
  3. ... where feature_id='F501';
  4. +--------------------------------+--------------+----------------+--------------------+
  5. | feature_name | is_supported | sub_feature_id | sub_feature_name |
  6. +--------------------------------+--------------+----------------+--------------------+
  7. | Features and conformance views | FALSE | | |
  8. | Features and conformance views | TRUE | 1 | SQL_FEATURES view |
  9. | Features and conformance views | FALSE | 2 | SQL_SIZING view |
  10. | Features and conformance views | FALSE | 3 | SQL_LANGUAGES view |
  11. +--------------------------------+--------------+----------------+--------------------+
  12. SELECT 4 rows in set (... sec)
NameData TypeNullable
feature_idStringNO
feature_nameStringNO
sub_feature_idStringNO
sub_feature_nameStringNO
is_supportedStringNO
is_verified_byStringYES
commentsStringYES
feature_id:

Identifier of the feature

feature_name:

Descriptive name of the feature by the Standard

sub_feature_id:

Identifier of the subfeature; If it has zero-length, this is a feature

sub_feature_name:

Descriptive name of the subfeature by the Standard; If it has zero-length, this is a feature

is_supported:

YES if the feature is fully supported by the current version of CrateDB, NO if not

is_verified_by:

Identifies the conformance test used to verify the claim;

Always NULL since the CrateDB development group does not perform formal testing of feature conformance

comments:

Either NULL or shows a comment about the supported status of the feature

ingestion_rules

The ingestion_rules table contains rules created by CREATE INGEST RULE statements.

Schema

NameData Type
rule_nameString
source_identString
target_tableString
conditionString
rule_name:The rule name
source_ident:The ingestion source identifier
target_table:The target table identifier
condition:A boolean expression used to filter the source data