psql -- Postgres interactive terminal
psql [ options ] [ dbname [ user ] ]
psql is a terminal-based front-end to Postgres. It enables you to type in queries interactively, issue them to Postgres, and see the query results. Alternatively, input can be from a file. In addition, it provides a number of meta-commands and various shell-like features to facilitate writing scripts and automating a wide variety of tasks.
psql is a regular Postgres client application. In order to connect to a database you need to know the name of your target database, the hostname and port number of the server and what user name you want to connect as. psql can be told about those parameters via command line options, namely -d, -h, -p, and -U respectively. If an argument is found that does not belong to any option it will be interpreted as the database name (or the user name, if the database name is also given). Not all these options are required, defaults do apply. If you omit the host name psql will connect via a Unix domain socket to a server on the local host. The default port number is compile-time determined. Since the database server uses the same default, you will not have to specify the port in most cases. The default user name is your Unix username, as is the default database name. Note that you can't just connect to any database under any username. Your database administrator should have informed you about your access rights. To save you some typing you can also set the environment variables PGDATABASE, PGHOST, PGPORT and PGUSER to appropriate values.
If the connection could not be made for any reason (e.g., insufficient privileges, postmaster is not running on the server, etc.), psql will return an error and terminate.
In normal operation, psql provides a prompt with the name of the database to which psql is currently connected, followed by the string ``=>''. For example,
$ psql testdb
Welcome to psql, the PostgreSQL interactive terminal.
Type: \copyright for distribution terms
\h for help with SQL commands
\? for help on internal slash commands
\g or terminate with semicolon to execute query
\q to quit
testdb=>
At the prompt, the user may type in SQL queries. Ordinarily, input
lines are sent to the backend when a query-terminating semicolon is
reached. An end of line does not terminate a query! Thus queries can
be spread over several lines for clarity. If the query was sent and
without error, the query results are displayed on the screen.
Whenever a query is executed, psql also polls for asynchronous notification events generated by LISTEN and NOTIFY.
Anything you enter in psql that begins with an unquoted backslash is a psql meta-command that is processed by psql itself. These commands are what makes psql interesting for administration or scripting. Meta-commands are more commonly called slash or backslash commands.
The format of a psql command is the backslash, followed immediately by a command verb, then any arguments. The arguments are separated from the command verb and each other by any number of whitespace characters.
To include whitespace into an argument you must quote it with a single quote. To include a single quote into such an argument, precede it by a backslash. Anything contained in single quotes is furthermore subject to C-like substitutions for \n (new line), \t (tab), \digits, \0digits, and \0xdigits (the character with the given decimal, octal, or hexadecimal code).
If an unquoted argument begins with a colon (:), it is taken as a variable and the value of the variable is taken as the argument instead.
Arguments that are quoted in backticks (`) are taken as a command line that is passed to the shell. The output of the command (with a trailing newline removed) is taken as the argument value. The above escape sequences also apply in backticks.
Some commands take the name of an SQL identifier (such as a table name) as argument. These arguments follow the syntax rules of SQL regarding double quotes: an identifier without double quotes is coerced to lower-case. For all other commands double quotes are not special and will become part of the argument.
Parsing for arguments stops when another unquoted backslash occurs. This is taken as the beginning of a new meta-command. The special sequence \\ (two backslashes) marks the end of arguments and continues parsing SQL queries, if any. That way SQL and psql commands can be freely mixed on a line. But in any case, the arguments of a meta-command cannot continue beyond the end of the line.
The following meta-commands are defined:
If username is omitted the current user name is assumed.
As a special rule, \connect without any arguments will connect to the default database as the default user (as you would have gotten by starting psql without any arguments).
If the connection attempt failed (wrong username, access denied, etc.), the previous connection will be kept if and only if psql is in interactive mode. When executing a non-interactive script, processing will immediately stop with an error. This distinction was chosen as a user convenience against typos on the one hand, and a safety mechanism that scripts are not accidentally acting on the wrong database on the other hand.
The syntax of the command is similar to that of the SQL COPY command (see its description for the details). Note that, because of this, special parsing rules apply to the \copy command. In particular, the variable substitution rules and backslash escapes do not apply.
Tip: This operation is not as efficient as the SQL COPY command because all data must pass through the client/server IP or socket connection. For large amounts of data the other technique may be preferable.
Note: Note the difference in interpretation of stdin and stdout between frontend and backend copies: in a frontend copy these always refer to psql's input and output stream. On a backend copy stdin comes from wherever the COPY itself came from (for example, a script run with the -f option), and stdout refers to the query output stream (see \o meta-command below).
The command form \d+ is identical, but any comments associated with the table columns are shown as well.
Note: If \d is called without any arguments, it is equivalent to \dtvs which will show a list of all tables, views, and sequences. This is purely a convenience measure.
Note: Postgres stores the object descriptions in the pg_description system table.
If pattern is specified, it is a regular expression that restricts the listing to those objects whose name matches. If one appends a + to the command name, each object is listed with its associated description, if any.
The new query buffer is then re-parsed according to the normal rules of psql, where the whole buffer is treated as a single line. (Thus you cannot make scripts this way. Use \i for that.) This means also that if the query ends with (or rather contains) a semicolon, it is immediately executed. In other cases it will merely wait in the query buffer.
Tip: psql searches the environment variables PSQL_EDITOR, EDITOR, and VISUAL (in that order) for an editor to use. If all of them are unset, /bin/vi is run.
Tip: If you use the \o command to redirect your query output you may wish to use \qecho instead of this command.
Note: To simplify typing, commands that consists of several words do not have to be quoted. Thus it is fine to type \help alter table.
Note: If you want to see the lines on the screen as they are read you must set the variable ECHO to all.
Tip: Use \lo_list to find out the large object's OID.
Note: See the description of the LO_TRANSACTION variable for important information concerning all large object operations.
Note that this command is subtly different from the server-side lo_import because it acts as the local user on the local file system, rather than the server's user and file system.
Note: See the description of the LO_TRANSACTION variable for important information concerning all large object operations.
Tip: Use \lo_list to find out the large object's OID.
Note: See the description of the LO_TRANSACTION variable for important information concerning all large object operations.
Query results includes all tables, command responses, and notices obtained from the database server, as well as output of various backslash commands that query the database (such as \d ), but not error messages.
Tip: To intersperse text output in between query results, use \qecho.
Adjustable printing options are:
Unaligned writes all fields of a tuple on a line, separated by the currently active field separator. This is intended to create output that might be intended to be read in by other programs (tab-separated, comma-separated).
Aligned mode is the standard, human-readable, nicely formatted text output that is default. The HTML and LATEX modes put out tables that are intended to be included in documents using the respective mark-up language. They are not complete documents! (This might not be so dramatic in HTML, but in LATEX you must have a complete document wrapper.)
Expanded mode is supported by all four output modes.
Note: This formerly only affected HTML mode. You can now set titles in any output format.
In any case, psql only uses the pager if it seems appropriate. That means among other things that the output is to a terminal and that the table would normally not fit on the screen. Because of the modular nature of the printing routines it is not always possible to predict the number of lines that will actually be printed. For that reason psql might not appear very discriminating about when to use the pager and when not to.
Note: It is an error to call \pset without arguments. In the future this call might show the current status of all printing options.
Note: As of psql version 7.0 it is no longer necessary to save the command history, since that will be done automatically on program termination. The history is also loaded automatically every time psql starts up.
Valid variable names can contain characters, digits, and underscores. See the section about psql variables for details.
Although you are welcome to set any variable to anything you want, psql treats several variables as special. They are documented in the section about variables.
Note: This command is totally separate from the SQL command SET.
test=> \z
Access permissions for database "test"
Relation | Access permissions
----------+-------------------------------------
my_table | { "=r","joe=arwR", "group staff=ar"}
(1 row )
Read this as follows:
The commands GRANT and REVOKE are used to set access permissions.
If so configured, psql understands both standard Unix short options, and GNU-style long options. The latter are not available on all systems.
query must be either a query string that is completely parseable by the backend (i.e., it contains no psql specific features), or it is a single backslash command. Thus you cannot mix SQL and psql meta-commands. To achieve that, you could pipe the string into psql, like this:
echo "\x \ \ select * from foo;" | psql.
Using this option is subtly different from writing psql < filename. In general, both will do what you expect, but using -f enables some nice features such as error messages with line numbers. There is also a slight chance that using this option will reduce the start-up overhead. On the other hand, the variant using the shell's input redirection is (in theory) guaranteed to yield exactly the same output that you would have gotten had you entered everything by hand.
Note: This mode is provided for those who insist on it, but you are not necessarily encouraged to use it. In particular, if you mix SQL and meta-commands on a line the order of execution might not always be clear to the inexperienced user.
This option is deprecated, as it is conceptually flawed. (Prompting for a non-default user name and prompting for a password because the backend requires it are really two different things.) You are encouraged to look at the -U and -W options instead.
As of version 7.0, psql automatically issues a password prompt whenever the backend requests password authentication. Because this is currently based on a hack, the automatic recognition might mysteriously fail, hence this option to force a prompt. If no password prompt is issued and the backend requires password authentication the connection attempt will fail.
psql provides variable substitution features similar to common Unix command shells. This feature is new and not very sophisticated, yet, but there are plans to expand it in the future. Variables are simply name/value pairs, where the value can be any string of any length. To set variables, use the psql meta-command \set:
testdb=> \set foo bar
sets the variable foo to the value bar. To retrieve
the content of the variable, precede the name with a colon and use
it as the argument of any slash command:
testdb=> \echo :foo
bar
Note: The arguments of \set are
subject to the same substitution rules as with other commands. Thus
you can construct interesting references such as \set
:foo 'something' and get soft links or variable variables,
of Perl or PHP fame, respectively. Unfortunately (or fortunately?),
there is no way to do anything useful with these constructs. On the
other hand, \set bar :foo is a perfectly valid
way to copy a variable.
If you call \set without a second argument, the variable is simply set, but has no value. To unset (or delete) a variable, use the command \unset.
psql's internal variable names can consist of letters, numbers, and underscores in any order and any number of them. A number of regular variables are treated specially by psql. They indicate certain option settings that can be changed at runtime by altering the value of the variable or represent some state of the application. Although you can use these variables for any other purpose, this is not recommended, as the program behavior might grow really strange really quickly. By convention, all specially treated variables consist of all upper-case letters (and possibly numbers and underscores). To ensure maximum compatibility in the future, avoid such variables. A list of all specially treated variables follows.
Note: This feature was shamelessly plagiarized from bash.
Note: This feature was shamelessly plagiarized from bash.
Note: This feature was shamelessly plagiarized from bash.
To choose what you want to do you set this variable to one of rollback, commit, or nothing. The default is to roll back the transaction. If you just want to load one or a few objects this is fine. However, if you intend to transfer many large objects, it might be advisable to provide one explicit transaction block around all commands.
An additional useful feature of psql variables is that you can substitute (interpolate) them into regular SQL statements. The syntax for this is again to prepend the variable name with a colon (:).
testdb=> \set foo 'my_table'
testdb=> SELECT * FROM :foo;
would then query the table my_table. The value of the variable is
copied literally, so it can even contain unbalanced quotes or backslash
commands. You must make sure that it makes sense where you put it.
Variable interpolation will not be performed into quoted SQL entities.
A popular application of this facility is to refer to the last inserted OID in subsequent statements to build a foreign key scenario. Another possible use of this mechanism is to copy the contents of a file into a field. First load the file into a variable and then proceed as above.
testdb=> \set content '\'' `cat my_file.txt` '\''
testdb=> INSERT INTO my_table VALUES (:content);
One possible problem with this approach is that my_file.txt might
contain single quotes. These need to be escaped so that they don't
cause a syntax error when the third line is processed. This could
be done with the program sed:
testdb=> \set content `sed -e "s/'/\\\\\\'/g" < my_file.txt`
Observe the correct number of backslashes (6)! You can resolve it
this way: After psql has parsed this line, it passes sed -e
"s/'/\ \ \'/g"
< my_file.txt to the shell. The shell will do it's own thing inside
the double quotes and execute sed with the arguments -e and s/'/\
\'/g. When sed parses this it will replace the two
backslashes with a single one and then do the substitution. Perhaps
at one point you thought it was great that all Unix commands use the
same escape character. And this is ignoring the fact that you might
have to escape all backslashes as well because SQL text constants
are also subject to certain interpretations. In that case you might
be better off preparing the file externally.
Since colons may legally appear in queries, the following rule applies: If the variable is not set, the character sequence colon+name is not changed. In any case you can escape a colon with a backslash to protect it from interpretation. (The colon syntax for variables is standard SQL for embedded query languages, such as ecpg. The colon syntax for array slices and type casts are Postgres extensions, hence the conflict.)
The prompts psql issues can be customized to your preference. The three variables PROMPT1, PROMPT2, and PROMPT3 contain strings and special escape sequences that describe the appearance of the prompt. Prompt 1 is the normal prompt that is issued when psql requests a new query. Prompt 2 is issued when more input is expected during query input because the query was not terminated with a semicolon or a quote was not closed. Prompt 3 is issued when you run an SQL COPY command and you are expected to type in the tuples on the terminal.
The value of the respective prompt variable is printed literally, except where a percent sign (%) is encountered. Depending on the next character, certain other text is substituted instead. Defined substitutions are:
psql returns 0 to the shell if it finished normally, 1 if a fatal error of its own (out of memory, file not found) occurs, 2 if the connection to the backend went bad and the session is not interactive, and 3 if an error occurred in a script and the variable ON_ERROR_STOP was set.
Before starting up, psql attempts to read and execute commands from the file $HOME/.psqlrc. It could be used to set up the client or the server to taste (using the \set and SET commands).
psql supports the readline and history libraries for convenient line editing and retrieval. The command history is stored in a file named .psql_history in your home directory and is reloaded when psql starts up. Tab-completion is also supported, although the completion logic makes no claim to be an SQL parser. When available, psql is automatically built to use these features. If for some reason you do not like the tab completion, you can turn if off by putting this in a file named .inputrc in your home directory:
$if psql
set disable-completion on
$endif
(This is not a psql but a readline feature. Read its documentation
for further details.)
If you have the readline library installed but psql does not seem to use it, you must make sure that Postgres's top-level configure script finds it. configure needs to find both the library libreadline.a (or a shared library equivalent) and the header files readline.h and history.h (or readline/readline.h and readline/history.h) in appropriate directories. If you have the library and header files installed in an obscure place you must tell configure about them, for example:
$ ./configure --with-includes=/opt/gnu/include --with-libs=/opt/gnu/lib ...
Then you have to recompile psql (not necessarily the entire code tree).
The GNU readline library can be obtained from the GNU project's FTP server at ftp://ftp.gnu.org.
Note: This section only shows a few examples specific to psql. If you want to learn SQL or get familiar with Postgres, you might wish to read the Tutorial that is included in the distribution.
The first example shows how to spread a query over several lines of input. Notice the changing prompt:
testdb=> CREATE TABLE my_table (
testdb(> first integer not null default 0,
testdb(> second text
testdb-> );
CREATE
Now look at the table definition again:
testdb=> \d my_table
Table "my_table"
Attribute | Type | Modifier
-----------+---------+--------------------
first | integer | not null default 0
second | text |
At this point you decide to change the prompt to something more interesting:
testdb=> \set PROMPT1 '%n@%m % %R%# '
peter@localhost testdb=>
Let's assume you have filled the table with data and want to take
a look at it:
peter@localhost testdb=> SELECT * FROM my_table;
first | second
-------+--------
1 | one
2 | two
3 | three
4 | four
(4 rows)
You can make this table look differently by using the \pset
command:
peter@localhost testdb=> \pset border 2
Border style is 2.
peter@localhost testdb=> SELECT * FROM my_table;
+-------+--------+
| first | second |
+-------+--------+
| 1 | one |
| 2 | two |
| 3 | three |
| 4 | four |
+-------+--------+
(4 rows)
peter@localhost testdb=> \pset border 0
Border style is 0.
peter@localhost testdb=> SELECT * FROM my_table;
first second
----- ------
1 one
2 two
3 three
4 four
(4 rows)
peter@localhost testdb=> \pset border 1
Border style is 1.
peter@localhost testdb=> \pset format unaligned
Output format is unaligned.
peter@localhost testdb=> \pset fieldsep ","
Field separator is ",".
peter@localhost testdb=> \pset tuples_only
Showing only tuples.
peter@localhost testdb=> SELECT second, first FROM my_table;
one,1
two,2
three,3
four,4
Alternatively, use the short commands:
peter@localhost testdb=> \a \t \x
Output format is aligned. Tuples only is off. Expanded display is on.
peter@localhost testdb=> SELECT * FROM my_table;
-[ RECORD 1 ]- first | 1 second | one
-[ RECORD 2 ]- first | 2 second | two
-[ RECORD 3 ]- first | 3 second | three
-[ RECORD 4 ]- first | 4 second | four
testdb=> \foo
Field separator is "oo", which is perhaps not what
one would expect.