PostgreSQL Naming Rules
This chapter covers the basic operation of PostgreSQL, including naming conventions, creating a database, and indexing.
PostgreSQL Naming Rules
When you create an object in PostgreSQL, you give that object a name. Every table has a name, every column has a name, and so on. PostgreSQL uses a single data type to define all object names: the name type.
A value of type name is a string of 63 or fewer characters1. A name must start with a letter or an underscore; the rest of the string can contain letters, digits, and underscores.
If you examine the entry corresponding to name in the pg_type table, you will find that a name is really 64 characters long. Because the name type is used internally by the PostgreSQL engine, it is a null-terminated string. So, the maximum length of a name value is 63 characters. You can enter more than 63 characters for an object name, but PostgreSQL stores only the first 63 characters.
Both SQL and PostgreSQL reserve certain words and normally, you cannot use those words to name objects. Examples of reserved words are
ANALYZE
BETWEEN
CHARACTER
INTEGER
CREATE
You cannot create a table named INTEGER or a column named BETWEEN. A complete list of reserved words can be found in Appendix B of the PostgreSQL User’s Guide.
If you find that you need to create an object that does not meet these rules, you can enclose the name in double quotes. Wrapping a name in quotes creates a quoted identifier. For example, you could create a table whose name is "3.14159"—the double quotes are required, but are not actually a part of the name (that is, they are not stored and do not count against the 63-character limit). When you create an object whose name must be quoted, you have to include the quotes not only when you create the object, but every time you refer to that object. For example, to select from the table mentioned previously, you would have to write
SELECT filling, topping, crust FROM "3.14159";
Here are a few examples of both valid and invalid names:
my_table -- valid
my_2nd_table -- valid
échéanciers -- valid: accented and non-Latin letters are allowed
"2nd_table" -- valid: quoted identifier
"create table" -- valid: quoted identifier
"1040Forms" -- valid: quoted identifier
2nd_table -- invalid: does not start with a letter or an underscore
Quoted names are case-sensitive. "1040Forms" and "1040FORMS" are two distinct names. Unquoted names are converted to lowercase, as shown here:
movies=# CREATE TABLE FOO( BAR INTEGER );
CREATE
movies=# CREATE TABLE foo( BAR INTEGER );
ERROR: Relation ‘foo’ already exists
movies=# \d
List of relations
Name | Type | Owner
------------------+-------+---------------
1040FORMS | table | bruce
1040Forms | table | sheila
customers | table | bruce
foo | table | bruce
rentals | table | bruce
tapes | table | bruce
(6 rows)
The names of all objects must be unique within some scope. Every database must have a unique name; the name of a schema must be unique within the scope of a single database, the name of a table must be unique within the scope of a single schema, and column names must be unique within a table. The name of an index must be unique within a database.
The Importance of the COMMENT Command
If you’ve been a programmer (or database developer) for more than, say, two days, you understand the importance of commenting your code. A comment helps new developers understand how your program (or database) is structured. It also helps you remember what you were thinking when you come back to work after a long weekend. If you’re writing procedural code (in C, Java, PL/pgSQL, or whatever language you prefer), you can intersperse comments directly into your code. If you’re creating objects in a PostgreSQL database, where do you store the comments? In the database, of course. The COMMENT command lets you associate a comment with just about any object that you can define in a PostgreSQL database. The syntax for the COMMENT command is very simple:
COMMENT ON object-type object-name IS comment-text;
where object-type and object-name are taken from the following:
DATABASE database-name
SCHEMA schema-name
TABLE table-name
COLUMN table-name.column-name
INDEX index-name
DOMAIN domain-name
TYPE data-type-name
VIEW view-name
CONSTRAINT constraint-name ON table-name
SEQUENCE sequence-name
TRIGGER trigger-name ON table-name
You can also define comments for other object types (functions, operators, rules, even languages), but the object types that we’ve shown here are the most common (see the PostgreSQL reference documentation for a complete list).
To add a comment to a table, for example, you would execute a command such as
COMMENT ON TABLE customers IS ‘List of active customers’;
You can only store one comment per object—if you COMMENT ON an object twice, the second comment replaces the first. To drop a comment, execute a COMMENT command, but specify NULL in place of the comment-text string, like this:
COMMENT ON TABLE customers IS NULL;
Once you have added a comment to an object, you can view the comment (in psql) using the command \dd object-name-pattern, like this:
movies=# \dd customers
Object descriptions
Schema | Name | Object | Description
--------+-----------+--------+--------------------------
public | customers | table | List of active customers
(1 row)
The \dd command will show you any commented object whose name matches the object-name-pattern. The \dd command will not show comments that you’ve assigned to a column within a table. To see column-related comments, use the command \d+ [table-name]. To see the comment assigned to each database, use the command \l+.