psql Application psql PostgreSQL interactive terminal 1999-10-26 psql [ options ] [ dbname [ user ] ] 1998-09-26 Input psql accepts many command-line arguments, a rich set of meta-commands, and the full SQL language supported by PostgreSQL. 1998-10-26 Output psql returns 0 to the shell on successful completion of all queries, 1 for fatal errors, 2 for abrupt disconnection from the backend, and 3 if a non-interactive script stopped because an SQL command or psql meta-command resulted in an error. 1998-10-26 Description psql is a character-based front-end to PostgreSQL. It enables you to type in queries interactively, issue them to PostgreSQL, and see the query results. 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 PostgreSQL client application. Hence, a postmaster process must be running on the database server host before psql is executed. In addition, the correct parameters to identify the database server, such as the postmaster host name, may need to be specified as described below. When psql starts, it reads SQL and psql commands from /etc/psqlrc and then from $HOME/.psqlrc This allows commands like \set or the SQL command , which can be used to set a variety of options, to be run at the start of every session. psql can be used in a pipe sequence, and automatically detects when it is not used interactively. 1998-09-26 Connecting To A Database psql attempts to make a connection to the database name at the hostname and port number, and with the user name specified on the command line. If any of these are omitted, the libpq client library, upon which psql is built, will choose defaults. (This will usually mean the environment variables PGDATABASE, PGHOST, PGPORT, PGUSER, respectively, if they are set. Otherwise the default host is the local host via Unix domain sockets, the default port is decided at compile time, the default user is the system user name, and the default database is the one with the same name as the user.) 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. 1998-09-26 Entering Queries In normal operation, psql provides a prompt with the name of the database that psql is currently connected to 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. If the database server reports success, the query results are displayed on the screen. Whenever a query is executed, psql also polls for asynchronous notification events generated by and . 1998-09-26 <application>psql</application> Meta-Commands Anything you enter in psql that begins with an unquoted backslash is a psql meta-command. Anything else is SQL and simply goes into the current query buffer (and once you have at least one complete query, it gets automatically submitted to the backend). For this reason, psql 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 white space characters. To include whitespace into an argument you must quote it with either single or double quotes. Anything contained in single quotes (except for a backslash-escaped single quote itself) is taken literally as the argument. Anything contained in double 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 dollar sign ($), it is taken as a variable and the value of the variable is taken as the argument instead. Inside double quotes, variable values can be substituted by enclosing the name in a ${...} sequence. See also under . Arguments that are quoted in back-ticks (`) 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. Back-ticks are subject to the same substitution rules as double-quotes. 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. In any case, the arguments of a meta-command cannot continue beyond the end of the line. The following meta-commands are defined: \a If the current table output format is unaligned, switch to aligned. If it is not unaligned, set it to unaligned. This command is kept for backwards compatibility. See \pset for a general solution. \C [ title ] Set the title of any tables being printed as the result of a query or unset any such title. This command is equivalent to \pset title title. (The name of this command derives from caption, as it was previously only used to set the caption in an HTML table.) \connect (or \c) [ dbname [ username ] ] Establishes a connection to a new database and/or under a user name. The previous connection is closed. If dbname is - the current database name is assumed. If username is omitted or - the current user name is assumed. If username is ? psql will prompt for the new user name interactively. 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. \copy [ binary ] table [ with oids ] { from | to } filename [ with delimiters 'character' ] Performs a frontend (client) copy. This is an operation that runs an SQL command, but instead of the backend reading or writing the specified file, and consequently requiring backend access and special user privilege, as well as being bound to the file system accessible by the backend, psql reads or writes the file and routes the data to or from the backend onto the local file system. The syntax of the command is in analogy to 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. 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 this other technique may be preferable. \copyright Shows the copyright and distribution terms of PostgreSQL. \d relation Shows all columns of relation (which could be a table, view, index, or sequence), their types, and any special attributes such as NOT NULL or defaults, if any. If the relation is, in fact, a table, any defined indices are also listed. If the relation is a view, the view definition is also shown. The command form \d? is identical, but any comments associated with the table columns are shown as well. 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. \da [ pattern ] Lists all available aggregate functions, together with the data type they operate on. If pattern (a regular expression) is specified, only matching aggregates are shown. If the alternative command form \da? is used, comments are listed for each function as well. The command form \da+ will show more information about each aggregate function, which is usually not of general interest. \dd [ object ] Shows the descriptions of object (which can be a regular expression), or of all objects if no argument is given. (Object covers aggregates, functions, operators, types, relations (tables, views, indices, sequences, large objects), rules, and triggers.) For example: => \dd version Object descriptions Name | What | Description ---------+----------+--------------------------- version | function | PostgreSQL version string (1 row) Descriptions for objects can be generated with the COMMENT ON SQL command. PostgreSQL stores the object descriptions in the pg_description system table. \df [ pattern ] Lists available functions, together with their argument and return types. If pattern (a regular expression) is specified, only matching functions are shown. If the form \df+ is used, additional information about each function is shown. Comments for each function can be shown with the \df? form. \distvS [ pattern ] This is not the actual command name: The letters i, s, t, v, S stand for index, sequence, table, view, and system table, respectively. You can specify any or all of them in any order to obtain a listing of them, together with who the owner is. If pattern is specified, it is a regular expression 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. \dl This is an alias for \lo_list, which shows a list of large objects. \do [ pattern ] Lists available operators with their operand and return types. If pattern is specified, only operators with that name will be shown. (Since this is a regular expression, be sure to quote all special characters in you operator name with backslashes. To prevent interpretation of the backslash as a new command, you might also wish to quote the argument.) If the form \do? is used, comments are listed for each operator. \dp [ pattern ] This is an alias for \z which was included for its greater mnemonic value (display permissions). \dT [ pattern ] Lists all data types or only those that match pattern. The command forms \dT+ and \dT? show extra information and the associated descriptions of the types, respectively. \edit (or \e) [ filename ] If filename is specified, the file is edited and after the editor exit its content is copied back to the query buffer. If no argument is given, the current query buffer is copied to a temporary file which is then edited in the same fashion. 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. 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. \echo text [ ... ] Prints the arguments to the standard output. This can be useful to intersperse information in the output of scripts. For example: => \echo `date` Tue Oct 26 21:40:57 CEST 1999 If you use the \o command to redirect your query output you may wish to use \qecho instead of this command. \f [ string ] Sets the field separator for unaligned query output. The default is | (a pipe symbol). See also \pset for a generic way of setting output options. \g [ { filename | |command } ] Sends the current query input buffer to the backend and optionally saves the output in filename or pipes the output into a separate Unix shell to execute command. A bare \g is virtually equivalent to a semicolon. A \g with argument is a one-shot alternative to the \o command. \help (or \h) [ command ] Give syntax help on the specified SQL command. If command is not specified, then psql will list all the commands for which syntax help is available. If command is an asterisk (*), then syntax help on all SQL commands is shown. To simplify typing, commands that consists of several words do not have to be quoted. Thus it is fine to type \help alter table. \H Turns on HTML query output format. If the HTML format is already on, it is switched back to the default aligned text format. This command is for compatibility and convenience, but see \pset about setting other output options. \i filename Reads input from the file filename and executes it as though it had been typed on the keyboard. If you want to see the lines on the screen as they are read you must set the variable echo. \l (or \list) List all the databases in the server as well as their owners. Append a ? (question mark) to the command name to see any descriptions for the databases as well. If your PostgreSQL installation was compiled with multibyte encoding support, the encoding scheme of each database is shown as well. \lo_export loid filename Reads the large object with OID loid from the database and writes it to filename. Note that this is subtly different from the server function lo_export, which acts with the permissions of the user that the database server runs as and on the server's file system. Use \lo_list to find out the large object's OID. See the description of the lo_transaction variable for important information concerning all large object operations. \lo_import filename [ comment ] Stores the file into a PostgreSQL large object. Optionally, it associates the given comment with the object. Example: foo=> \lo_import '/home/me/pictures/photo.xcf' 'a picture of me' lo_import 152801 The response indicates that the large object received object id 152801 which one ought to remember if one wants to access the object ever again. For that reason it is recommended to always associate a human-readable comment with every object. Those can then be seen with the \lo_list? command. 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. See the description of the lo_transaction variable for important information concerning all large object operations. \lo_list Shows a list of all PostgreSQL large objects currently stored in the database along with their owners. Append a question mark to the command name (\lo_list?) to see the the associated comments as well. \lo_unlink loid Deletes the large object with OID loid from the database. Use \lo_list to find out the large object's OID. See the description of the lo_transaction variable for important information concerning all large object operations. \o [ {filename | |command} ] Saves future query results to the file filename or pipe future results into a separate Unix shell to execute command. If no arguments are specified, the query output will be reset to stdout. Query results includes all tables and notices obtained from the database server, as well as output of various backslash commands that query the database (such as \d). To intersperse text output in between query results, use \qecho. \p Print the current query buffer to the standard output. \pset parameter [ value ] This command sets options affecting the output of query result tables. parameter describes which option is to be set. The semantics of value depend thereon. Adjustable printing options are: format Sets the output format to one of unaligned, aligned, html, or latex. Unique abbreviations are allowed. (That would mean one letter is enough.) 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.) border The second argument must be a number. In general, the higher the number the more borders and lines the tables will have, but this depends on the particular format. In HTML mode, this will translate directly into the border=... attribute, in the others only values 0 (no border), 1 (internal dividing lines), and 2 (table frame) make sense. expanded (or x) Toggles between regular and expanded format. When expanded format is enabled, all output has two columns with the field name on the left and the data on the right. This mode is useful if the data wouldn't fit on the screen in the normal horizontal mode. Expanded mode is support by all four output modes. null The second argument is a string that should be printed whenever a field is null. The default is not to print anything, which can easily be mistaken for, say, an empty string. Thus, one might choose to write \pset null "(null)". fieldsep Specifies the field separator to be used in unaligned output mode. That way one can create, for example, tab- or comma-separated output, which other programs might prefer. To set a tab as field separator, type \pset fieldsep "\t". The default field separator is | (a pipe symbol). tuples_only (or t) Toggles between tuples only and full display. Full display may show extra information such as column headers, titles, and various footers. In tuples only mode, only actual table data is shown. title [ text ] Sets the table title for any subsequently printed tables. This can be used to give your output descriptive tags. If no argument is given, the title is unset. This formerly only affected HTML mode. You can now set titles in any output format. tableattr (or T) [ text ] Allows you to specify any attributes to be places inside the HTML table tag. This could for example be cellpadding or bgcolor. Note that you probably don't want to specify border here, as that is already taken care of by \pset border. pager Toggles the list of a pager to do table output. If the environment variable PAGER is set, the output is piped to the specified program. Otherwise /bin/more is assumed. 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. Illustrations on how these different formats look can be seen in the section. There are various shortcut commands for \pset. See \a, \C, \H, \t, \T, and \x. It is an error to call \pset without arguments. In the future this call might show the current status of all printing options. \q Quit the psql program. \qecho text [ ... ] This command is identical to \echo except that all output will be written to the query output channel, as set by \o. \r Resets (clears) the query buffer. \s [ filename ] Print or save the command line history to filename. If filename is omitted, the history is written to the standard output. This option is only available if psql is configured to use the GNU history library. As of psql version 7.0 it is no longer necessary, in fact, to save the command history as that will be done automatically on program termination. The history is then also automatically loaded every time psql starts up. \set [ name [ value ]] Sets the internal variable name to value. If no second argument is given, the variable is unset (which is different from setting it to, for example, an empty string: \set foo ''). If no arguments are given, all currently defined variables are listed with their values. 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 to, psql treats several variables special. They are documented in the section about variables. This command is totally separate from the SQL command . \t Toggles the display of output column name headings and row count footer. This command is equivalent to \pset tuples_only and is provided for convenience. \T table_options Allows you to specify options to be placed within the table tag in HTML tabular output mode. This command is equivalent to \pset tableattr table_options. \w {filename | |command} Outputs the current query buffer to the file filename or pipes it to the Unix command command. \x Toggles extended row format mode. As such it is equivalent to \pset expanded. \z [ pattern ] Produces a list of all tables in the database with their appropriate access permissions listed. If an argument is given it is taken as a regular expression which limits the listing to those tables which match it. test=> \z Access permissions for database "test" Relation | Access permissions ----------+------------------------------------- my_table | {"=r","joe=arwR", "group staff=ar"} (1 row ) Read this as follows: "=r": PUBLIC has read (SELECT) permission on the table. "joe=arwR": User joe has read, write (UPDATE, DELETE), append (INSERT) permissions, and permission to create rules on the table. "group staff=ar": Group staff has SELECT and INSERT permission. The commands and are used to set access permissions. \! [ command ] Escapes to a separate Unix shell or executes the Unix command command. The arguments are not further interpreted, the shell will see them as is. If you wish to capture the output of a shell command and/or use psql's variable substitution features, use the backticks (`). \? Get help information about the slash (\) commands. 1998-09-26 Command-line Options If so configured, psql understands both standard Unix short options, and GNU-style long options. Since the latter are not available on all systems, you are advised to consider carefully whether to use them, if you are writing scripts, etc. For support on the PostgreSQL mailing lists, you are asked to only use the standard short options. Many command line options are equivalent to an internal slash command or to setting some variable. Those will not be explained in detail here. Instead, you are asked to look them up in the respective section. -A, --no-align Switches to unaligned output mode. (The default output mode is otherwise aligned.) -c, --command query Specifies that psql is to execute one query string, query, and then exit. This is useful for shell scripts, typically in conjunction with the option. 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 this you could pipe the string into psql and finish it with a a \q, like so: echo "select * from foo; \q" | psql. -d, --dbname dbname Specifies the name of the database to connect to. This is equivalent to specifying dbname as the first non-option argument on the command line. -e, --echo In non-interactive mode, all lines are printed to the screen as they are read. This is equivalent to setting the variable echo. -E, --echo-all Echos the actual queries generated by \d and other backslash commands. You can use this if you wish to include similar functionality into your own programs. This is equivalent to setting the variable echo_secret from within psql. -f, --file filename Use the file filename as the source of queries instead of reading queries interactively. After the file is processed, psql terminates. This in many ways equivalent to the internal command \i. -F, --field-sep separator Use separator as the field separator. This is equivalent to \pset fieldsep or \f. -h, --host hostname Specifies the host name of the machine on which the postmaster is running. Without this option, communication is performed using local Unix domain sockets. -H, --html Turns on HTML tabular output. This is equivalent to \pset format html or the \H command. -l, --list Lists all available databases, then exits. Other non-connection options are ignored. This is similar to the internal command \list. -n, --no-readline Do not use the readline library for input line editing and command history. -o, --out filename Put all query output into file filename. This is equivalent to the command \o. -p, --port port Specifies the TCP/IP port or, by omission, the local Unix domain socket file extension on which the postmaster is listening for connections. Defaults to the value of the PGPORT environment variable or, if not set, to the port specified at compile time, usually 5432. -P, --pset assignment Allows you to specify printing options in the style of \pset on the command line. Note that here you have to separate name and value with an equal sign instead of a space. Thus to set the output format to LaTeX, you could write -P format=latex. -q Specifies that psql should do its work quietly. By default, it prints welcome messages, various informational output and prompts for each query. If this option is used, none of this happens. This is useful with the option. Within psql you can also set the quiet variable to achieve the same effect. -s, --single-step Run in single-step mode. That means the user is prompted before each query is sent to the backend, with the option to cancel execution as well. Use this to debug scripts. -S, --single-line Runs in single-line mode where a newline sends a query, in addition to a semicolon. 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 unexperienced user. Moral: Unless you exclusively type short queries, avoid using this mode. -t, --tuples-only Turn off printing of column names and result row count footers, etc. It is completely equivalent to the \t. -T, --table-attr table_options Allows you to specify options to be placed within the HTML table tag. See \pset for details. -u Makes psql prompt for the user name and password before connecting to the database. 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 and options instead. -U, --username username Connects to the database as the user username instead of the default. (You must have permission to do so, of course.) If username is ?, psql issues an interactive prompt for the user name. -v, --variable, --set assignment Performs a variable assignment, like the \set internal command. Note that you must separate name and value, if any, by an equal sign on the command line. -V, --version Shows version information about psql and your PostgreSQL database server, if it could be reached. The output looks similar to this: ~$ psql -V Server: PostgreSQL 6.5.2 on i586-pc-linux-gnu, compiled by egcs psql 6.6.0 on i586-pc-linux-gnu, compiled by gcc 2.8.1 (Oct 27 1999 15:15:04), long options, readline, history, locale, assert checks The Server line is identical to the one returned by the backend function version() and thus might vary if you query different servers by using different connection options. The psql line is compiled into the psql binary. It shows you which PostgreSQL release it was distributed with and what optional features were compiled into it. Although in general (as in the example above) you can use psql and database servers from different versions (if they don't differ too much) this is not recommended or even necessary. The optional features indicate only psql's capabilities but if psql was configured with the same source tree as the rest of the distribution, it gives you an indication about other parts of the installation as well. -W Requests that psql should prompt for a password before connecting to a database. This will remain set for the entire session, even if you change the database connection with the meta-command \connect. 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 content of the environment variable PGPASSWORD is taken. If this is not set, the connection attempt will fail. If you are considering setting the variable PGPASSWORD to do authentication, you have a problem. -x Turns on extended row format mode. This is equivalent to the command \x. You may set environment variables to avoid typing some of the above options. See the section Connection To A Database above and in particular the documentation of the libpq client library. 1998-09-27 Advanced features Variables psql provides variable substitution features similar to common Unix command shells. 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 dollar-sign and use it as the argument of any slash command: testdb=> \echo $foo bar Alternatively, the value can also be interpolated into a double-quoted (or backtick-quoted) string, like so: testdb=> \echo "foo is now ${foo}." foo is now bar. (The curly braces are required. This is not Perl.) No variable substitution will be performed in single-quoted strings or in any of the backslash commands that have special parsing rules (e.g., \copy). 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}bar" 'something' and get soft links or variable variables of Perl or PHP fame, respectively. Unfortunately (or fortunately?), there is not way to do anything useful with these constructs. (\echo ${${foo}} doesn't work.) On the other hand, \set bar $foo is a perfectly valid way to copy a variable. psql's internal variable names can consist of letters, numbers, and underscores in any order and any number of them. It is recommended, however, that you stick to lower-case letters and do not begin with a digit. The partial rationale for this follows. If you attempt to refer to a variable that is not set, psql first checks if it is the name of one of several defined magic variables. Those variables are maintained internally and always have a value (at least when their semantics permit it). By convention they all start with an upper-case letter. You can set those variables manually, but that will shadow their special meaning, until you unset your personal copy. Finally, if no match is found that way, the value of the respective environment variable is substituted. Currently, the following magic variables are defined: Version which contains a string with the version of psql; Database, Host, Port, User are the currently active connection options. LastOid contains the oid that was the result of the last INSERT or \lo_import command. If the last command was not one of those two, the value is undefined. 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. Although you can use these variables for any other purpose, this is not recommended, as the program behavior might grow really strange really quickly. Note that the majority variables are boolean variables, that is, they only care whether or not are they set, not what to. A list of all specially treated variables follows. die_on_error By default, if non-interactive scripts encounter an error, such as a malformed SQL query or internal meta-command, processing continues. This is often less than desirable. If this variable is set, script processing will immediately terminate. If the script was called from another script it will terminate in the same fashion. If the outermost script was not called from an interactive psql session but rather using the option, psql will return error code 3, to distinguish this case from fatal error conditions (error code 1). echo If set, all lines from a script are written to the standard output before they are executed. To specify this on program startup, in conjunction with the option perhaps, use the switch . echo_secret When this variable is set and a backslash command queries the database, the query is first shown. This way you can study the PostgreSQL internals and provide similar functionality in your own programs. If you set the variable to the value noexec, the queries are just shown but are not actually sent to the backend and executed. lo_transaction If you use the PostgreSQL large object interface to specially store data that does not fit into one tuple, all the operations must be contained in a transaction block. (See the documentation of the large object interface for more information.) Since psql has no way to keep track if you already have a transaction in progress when you call one of its internal commands \lo_export, \lo_import, \lo_unlink it must take some arbitrary action. This action could either be to roll back any transaction that might already be in progress, or to commit any such transaction, or to do nothing at all. In the latter case you must provide you own BEGIN TRANSACTION/COMMIT block or the results will be unpredictable (usually resulting in the desired action not being performed anyway). 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. prompt1, prompt2, prompt3 These specify what the prompt psql issues is supposed to look like. See below. quiet This variable is equivalent to the command line option . It is probably not too useful in interactive mode. singleline This variable is set be the command line options . You can unset or reset it at run time. singlestep This variable is equivalent to the command line option . <acronym>SQL</acronym> Interpolation An additional useful feature of psql variables is that you can substitute (interpolate) them into regular SQL statements. The syntax for this is 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 statement 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=> \set content "'${content}'" 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. Prompting 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: %M The hostname of the database server (or . if Unix domain socket). %m The hostname of the database server truncated after the first dot. %> The port number at which the database server is listening. %n The username you are connected as (not your local system user name). %/ The name of the current database. %~ Like %/, but the output is ~ (tilde) if the database is your default database. %# If the username is postgres, a #, otherwise a >. %R In prompt 1 normally =, but ^ if in single-line mode, and ! if the session is disconnected from the database (which can only happen if \connect fails). In prompt 2 the sequence is replaced by -, *, a single quote, or a double quote, depending on whether psql expects more input because the query wasn't terminated yet, because you are inside a /* ... */ comment, or because you are inside a quote. In prompt 3 the sequence doesn't resolve to anything. %digits If digits starts with 0x the rest of the characters are interpreted at a hexadecimal digit and the character with the corresponding code is subsituted. If the first digit is 0 the characters are interpreted as on octal number and the corresponding character is substituted. Otherwise a decimal number is assumed. %$name$ The value of the psql, magic, or environment variable name. See the section for details. %`command` The output of command, similar to ordinary back-tick substitution. To insert a percent sign into your prompt, write %%. The default prompts are equivalent to '%/%R%# ' for prompts 1 and 2, and '>> ' for prompt 3. Examples This section only shows a few examples specific to psql. If you want to learn SQL or get familiar with PostgreSQL, 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 int4 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 | Info -----------+------+-------------------- first | int4 | 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) Notice how the int4 colums in right aligned while the text column in left aligned. 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 1999-10-27 Appendix Bugs and Issues In some earlier life psql allowed the first argument to start directly after the (single-letter) command. For compatibility this is still supported to some extent but I am not going to explain the details here as this use is discouraged. But if you get strange messages, keep this in mind. For example testdb=> \foo Field separator is "oo". is perhaps not what one would expect. There are about three different parsers in psql, in addition to the backend SQL parser, all doing their own thing and attempting to get along with each other. Sometimes they do, sometimes they don't. An excellent example of this can be seen in section . There are vague dreams of using flex in the future, but it won't happen soon. Several string buffers are assigned fixed sizes at compile time. These are usually based on certain settings about what the backend can accept for a particular quantity. If you use psql with a different backend than the one it was configured for, you might encounter these limits sooner rather than later. The number of options for a backslash command is limited, probably to 16. You can easily change this in the source code, and perhaps I will get around to fixing this one day (see previous item). Not that there is any command that actually uses that many options though. History and Lineage psql first appeared in Postgres95 to complement and later replace the monitor program. (You see this name here or there in really old files. The author has never had the pleasure to use this program though.) An uncountable number of people have added features since to reflect the enhancements in the actual database server. The present version is the result of a major clean-up and re-write in 1999 by Peter Eisentraut in preparation for release 7.0. Many people had again contributed their ideas. A bunch of features were stolen from various shells (in case you hadn't noticed), in particular tcsh. <acronym>GNU</acronym> readline A great deal of psql's convenience is owed to it using the GNU readline and history library for accepting and storing user input. To verify whether your copy of psql was compiled with readline support, execute psql -V and check the output for the words readline and history. If you have the readline library installed but psql does not seem to use it, you must make sure that PostgreSQL's top-level configure script finds it. configure needs to find both the library libreadline.a (or libreadline.so on systems with shared libraries) 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-libraries=/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.