<!-- $Header: /cvsroot/pgsql/doc/src/sgml/ref/psql-ref.sgml,v 1.92 2003/07/27 03:32:26 momjian Exp $ PostgreSQL documentation --> <refentry id="APP-PSQL"> <refmeta> <refentrytitle id="app-psql-title"><application>psql</application></refentrytitle> <manvolnum>1</manvolnum> <refmiscinfo>Application</refmiscinfo> </refmeta> <refnamediv> <refname><application>psql</application></refname> <refpurpose> <productname>PostgreSQL</productname> interactive terminal </refpurpose> </refnamediv> <refsynopsisdiv> <cmdsynopsis> <command>psql</command> <arg rep="repeat"><replaceable class="parameter">option</replaceable></arg> <arg><replaceable class="parameter">dbname</replaceable> <arg><replaceable class="parameter">username</replaceable></arg></arg> </cmdsynopsis> </refsynopsisdiv> <refsect1> <title>Description</title> <para> <application>psql</application> is a terminal-based front-end to <productname>PostgreSQL</productname>. It enables you to type in queries interactively, issue them to <productname>PostgreSQL</productname>, 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. </para> </refsect1> <refsect1 id="R1-APP-PSQL-3"> <title>Options</title> <variablelist> <varlistentry> <term><option>-a</></term> <term><option>--echo-all</></term> <listitem> <para> Print all the lines to the screen as they are read. This is more useful for script processing rather than interactive mode. This is equivalent to setting the variable <varname>ECHO</varname> to <literal>all</literal>. </para> </listitem> </varlistentry> <varlistentry> <term><option>-A</></term> <term><option>--no-align</></term> <listitem> <para> Switches to unaligned output mode. (The default output mode is otherwise aligned.) </para> </listitem> </varlistentry> <varlistentry> <term><option>-c <replaceable class="parameter">command</replaceable></></term> <term><option>--command <replaceable class="parameter">command</replaceable></></term> <listitem> <para> Specifies that <application>psql</application> is to execute one command string, <replaceable class="parameter">command</replaceable>, and then exit. This is useful in shell scripts. </para> <para> <replaceable class="parameter">command</replaceable> must be either a command string that is completely parsable by the server (i.e., it contains no <application>psql</application> specific features), or it is a single backslash command. Thus you cannot mix <acronym>SQL</acronym> and <application>psql</application> meta-commands. To achieve that, you could pipe the string into <application>psql</application>, like this: <literal>echo "\x \\ select * from foo;" | psql</literal>. </para> <para> If the command string contains multiple SQL commands, they are processed in a single transaction, unless there are explicit BEGIN/COMMIT commands included in the string to divide it into multiple transactions. This is different from the behavior when the same string is fed to psql's standard input. </para> </listitem> </varlistentry> <varlistentry> <term><option>-d <replaceable class="parameter">dbname</replaceable></></term> <term><option>--dbname <replaceable class="parameter">dbname</replaceable></></term> <listitem> <para> Specifies the name of the database to connect to. This is equivalent to specifying <replaceable class="parameter">dbname</replaceable> as the first non-option argument on the command line. </para> </listitem> </varlistentry> <varlistentry> <term><option>-e</></term> <term><option>--echo-queries</></term> <listitem> <para> Show all commands that are sent to the server. This is equivalent to setting the variable <varname>ECHO</varname> to <literal>queries</literal>. </para> </listitem> </varlistentry> <varlistentry> <term><option>-E</></term> <term><option>--echo-hidden</></term> <listitem> <para> Echo the actual queries generated by <command>\d</command> 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 <varname>ECHO_HIDDEN</varname> from within <application>psql</application>. </para> </listitem> </varlistentry> <varlistentry> <term><option>-f <replaceable class="parameter">filename</replaceable></></term> <term><option>--file <replaceable class="parameter">filename</replaceable></></term> <listitem> <para> Use the file <replaceable class="parameter">filename</replaceable> as the source of commands instead of reading commands interactively. After the file is processed, <application>psql</application> terminates. This is in many ways equivalent to the internal command <command>\i</command>. </para> <para> If <replaceable>filename</replaceable> is <literal>-</literal> (hyphen), then standard input is read. </para> <para> Using this option is subtly different from writing <literal>psql < <replaceable class="parameter">filename</replaceable></literal>. In general, both will do what you expect, but using <literal>-f</literal> 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. </para> </listitem> </varlistentry> <varlistentry> <term><option>-F <replaceable class="parameter">separator</replaceable></></term> <term><option>--field-separator <replaceable class="parameter">separator</replaceable></></term> <listitem> <para> Use <replaceable class="parameter">separator</replaceable> as the field separator. This is equivalent to <command>\pset fieldsep</command> or <command>\f</command>. </para> </listitem> </varlistentry> <varlistentry> <term><option>-h <replaceable class="parameter">hostname</replaceable></></term> <term><option>--host <replaceable class="parameter">hostname</replaceable></></term> <listitem> <para> Specifies the host name of the machine on which the server is running. If the value begins with a slash, it is used as the directory for the Unix-domain socket. </para> </listitem> </varlistentry> <varlistentry> <term><option>-H</></term> <term><option>--html</></term> <listitem> <para> Turn on <acronym>HTML</acronym> tabular output. This is equivalent to <literal>\pset format html</literal> or the <command>\H</command> command. </para> </listitem> </varlistentry> <varlistentry> <term><option>-l</></term> <term><option>--list</></term> <listitem> <para> List all available databases, then exits. Other non-connection options are ignored. This is similar to the internal command <command>\list</command>. </para> </listitem> </varlistentry> <varlistentry> <term><option>-o <replaceable class="parameter">filename</replaceable></></term> <term><option>--output <replaceable class="parameter">filename</replaceable></></term> <listitem> <para> Put all query output into file <replaceable class="parameter">filename</replaceable>. This is equivalent to the command <command>\o</command>. </para> </listitem> </varlistentry> <varlistentry> <term><option>-p <replaceable class="parameter">port</replaceable></></term> <term><option>--port <replaceable class="parameter">port</replaceable></></term> <listitem> <para> Specifies the TCP port or the local Unix domain socket file extension on which the server is listening for connections. Defaults to the value of the <envar>PGPORT</envar> environment variable or, if not set, to the port specified at compile time, usually 5432. </para> </listitem> </varlistentry> <varlistentry> <term><option>-P <replaceable class="parameter">assignment</replaceable></></term> <term><option>--pset <replaceable class="parameter">assignment</replaceable></></term> <listitem> <para> Allows you to specify printing options in the style of <command>\pset</command> 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 <literal>-P format=latex</literal>. </para> </listitem> </varlistentry> <varlistentry> <term><option>-q</></term> <term><option>--quiet</></term> <listitem> <para> Specifies that <application>psql</application> should do its work quietly. By default, it prints welcome messages and various informational output. If this option is used, none of this happens. This is useful with the <option>-c</option> option. Within <application>psql</application> you can also set the <varname>QUIET</varname> variable to achieve the same effect. </para> </listitem> </varlistentry> <varlistentry> <term><option>-R <replaceable class="parameter">separator</replaceable></></term> <term><option>--record-separator <replaceable class="parameter">separator</replaceable></></term> <listitem> <para> Use <replaceable class="parameter">separator</replaceable> as the record separator. This is equivalent to the <command>\pset recordsep</command> command. </para> </listitem> </varlistentry> <varlistentry> <term><option>-s</></term> <term><option>--single-step</></term> <listitem> <para> Run in single-step mode. That means the user is prompted before each command is sent to the server, with the option to cancel execution as well. Use this to debug scripts. </para> </listitem> </varlistentry> <varlistentry> <term><option>-S</></term> <term><option>--single-line</></term> <listitem> <para> Runs in single-line mode where a newline terminates an SQL command, as a semicolon does. </para> <note> <para> This mode is provided for those who insist on it, but you are not necessarily encouraged to use it. In particular, if you mix <acronym>SQL</acronym> and meta-commands on a line the order of execution might not always be clear to the inexperienced user. </para> </note> </listitem> </varlistentry> <varlistentry> <term><option>-t</></term> <term><option>--tuples-only</></term> <listitem> <para> Turn off printing of column names and result row count footers, etc. It is completely equivalent to the <command>\t</command> meta-command. </para> </listitem> </varlistentry> <varlistentry> <term><option>-T <replaceable class="parameter">table_options</replaceable></></term> <term><option>--table-attr <replaceable class="parameter">table_options</replaceable></></term> <listitem> <para> Allows you to specify options to be placed within the <acronym>HTML</acronym> <sgmltag>table</sgmltag> tag. See <command>\pset</command> for details. </para> </listitem> </varlistentry> <varlistentry> <term><option>-u</></term> <listitem> <para> Makes <application>psql</application> prompt for the user name and password before connecting to the database. </para> <para> This option is deprecated, as it is conceptually flawed. (Prompting for a non-default user name and prompting for a password because the server requires it are really two different things.) You are encouraged to look at the <option>-U</option> and <option>-W</option> options instead. </para> </listitem> </varlistentry> <varlistentry> <term><option>-U <replaceable class="parameter">username</replaceable></></term> <term><option>--username <replaceable class="parameter">username</replaceable></></term> <listitem> <para> Connect to the database as the user <replaceable class="parameter">username</replaceable> instead of the default. (You must have permission to do so, of course.) </para> </listitem> </varlistentry> <varlistentry> <term><option>-v <replaceable class="parameter">assignment</replaceable></></term> <term><option>--set <replaceable class="parameter">assignment</replaceable></></term> <term><option>--variable <replaceable class="parameter">assignment</replaceable></></term> <listitem> <para> Perform a variable assignment, like the <command>\set</command> internal command. Note that you must separate name and value, if any, by an equal sign on the command line. To unset a variable, leave off the equal sign. To just set a variable without a value, use the equal sign but leave off the value. These assignments are done during a very early stage of start-up, so variables reserved for internal purposes might get overwritten later. </para> </listitem> </varlistentry> <varlistentry> <term><option>-V</></term> <term><option>--version</></term> <listitem> <para> Show the <application>psql</application> version. </para> </listitem> </varlistentry> <varlistentry> <term><option>-W</></term> <term><option>--password</></term> <listitem> <para> Requests that <application>psql</application> 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 <command>\connect</command>. </para> <para> In the current version, <application>psql</application> automatically issues a password prompt whenever the server 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 server requires password authentication the connection attempt will fail. </para> </listitem> </varlistentry> <varlistentry> <term><option>-x</></term> <term><option>--expanded</></term> <listitem> <para> Turn on the extended table formatting mode. This is equivalent to the command <command>\x</command>. </para> </listitem> </varlistentry> <varlistentry> <term><option>-X,</></term> <term><option>--no-psqlrc</></term> <listitem> <para> Do not read the start-up file <filename>~/.psqlrc</filename>. </para> </listitem> </varlistentry> <varlistentry> <term><option>-?</></term> <term><option>--help</></term> <listitem> <para> Show help about <application>psql</application> command line arguments. </para> </listitem> </varlistentry> </variablelist> </refsect1> <refsect1> <title>Exit Status</title> <para> <application>psql</application> 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 server went bad and the session was not interactive, and 3 if an error occurred in a script and the variable <varname>ON_ERROR_STOP</varname> was set. </para> </refsect1> <refsect1> <title>Usage</title> <refsect2 id="R2-APP-PSQL-connecting"> <title>Connecting To A Database</title> <para> <application>psql</application> is a regular <productname>PostgreSQL</productname> client application. In order to connect to a database you need to know the name of your target database, the host name and port number of the server and what user name you want to connect as. <application>psql</application> can be told about those parameters via command line options, namely <option>-d</option>, <option>-h</option>, <option>-p</option>, and <option>-U</option> 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, <application>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 user name, as is the default database name. Note that you can't just connect to any database under any user name. Your database administrator should have informed you about your access rights. To save you some typing you can also set the environment variables <envar>PGDATABASE</envar>, <envar>PGHOST</envar>, <envar>PGPORT</envar> and <envar>PGUSER</envar> to appropriate values. </para> <para> If the connection could not be made for any reason (e.g., insufficient privileges, server is not running on the targeted host, etc.), <application>psql</application> will return an error and terminate. </para> </refsect2> <refsect2 id="R2-APP-PSQL-4"> <title>Entering SQL Commands</title> <para> In normal operation, <application>psql</application> provides a prompt with the name of the database to which <application>psql</application> is currently connected, followed by the string <literal>=></literal>. For example, <programlisting> $ <userinput>psql testdb</userinput> Welcome to psql &version;, 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=> </programlisting> </para> <para> At the prompt, the user may type in <acronym>SQL</acronym> commands. Ordinarily, input lines are sent to the server when a command-terminating semicolon is reached. An end of line does not terminate a command. Thus commands can be spread over several lines for clarity. If the command was sent and without error, the results of the command are displayed on the screen. </para> <para> Whenever a command is executed, <application>psql</application> also polls for asynchronous notification events generated by <xref linkend="SQL-LISTEN" endterm="SQL-LISTEN-title"> and <xref linkend="SQL-NOTIFY" endterm="SQL-NOTIFY-title">. </para> </refsect2> <refsect2> <title>Meta-Commands</title> <para> Anything you enter in <application>psql</application> that begins with an unquoted backslash is a <application>psql</application> meta-command that is processed by <application>psql</application> itself. These commands are what makes <application>psql</application> interesting for administration or scripting. Meta-commands are more commonly called slash or backslash commands. </para> <para> The format of a <application>psql</application> 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. </para> <para> To include whitespace into an argument you may 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 <literal>\n</literal> (new line), <literal>\t</literal> (tab), <literal>\</literal><replaceable>digits</replaceable>, <literal>\0</literal><replaceable>digits</replaceable>, and <literal>\0x</literal><replaceable>digits</replaceable> (the character with the given decimal, octal, or hexadecimal code). </para> <para> If an unquoted argument begins with a colon (<literal>:</literal>), it is taken as a <application>psql</> variable and the value of the variable is used as the argument instead. </para> <para> Arguments that are enclosed in backquotes (<literal>`</literal>) are taken as a command line that is passed to the shell. The output of the command (with any trailing newline removed) is taken as the argument value. The above escape sequences also apply in backquotes. </para> <para> Some commands take an <acronym>SQL</acronym> identifier (such as a table name) as argument. These arguments follow the syntax rules of <acronym>SQL</acronym>: Unquoted letters are forced to lowercase, while double quotes (<literal>"</>) protect letters from case conversion and allow incorporation of whitespace into the identifier. Within double quotes, paired double quotes reduce to a single double quote in the resulting name. For example, <literal>FOO"BAR"BAZ</> is interpreted as <literal>fooBARbaz</>, and <literal>"A weird"" name"</> becomes <literal>A weird" name</>. </para> <para> Parsing for arguments stops when another unquoted backslash occurs. This is taken as the beginning of a new meta-command. The special sequence <literal>\\</literal> (two backslashes) marks the end of arguments and continues parsing <acronym>SQL</acronym> commands, if any. That way <acronym>SQL</acronym> and <application>psql</application> 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. </para> <para> The following meta-commands are defined: <variablelist> <varlistentry> <term><literal>\a</literal></term> <listitem> <para> If the current table output format is unaligned, it is switched to aligned. If it is not unaligned, it is set to unaligned. This command is kept for backwards compatibility. See <command>\pset</command> for a general solution. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\cd</literal> <optional><replaceable>directory</replaceable></optional></term> <listitem> <para> Changes the current working directory to <replaceable>directory</replaceable>. Without argument, changes to the current user's home directory. </para> <tip> <para> To print your current working directory, use <literal>\!pwd</literal>. </para> </tip> </listitem> </varlistentry> <varlistentry> <term><literal>\C</literal> [ <replaceable class="parameter">title</replaceable> ]</term> <listitem> <para> Sets the title of any tables being printed as the result of a query or unset any such title. This command is equivalent to <literal>\pset title <replaceable class="parameter">title</replaceable></literal>. (The name of this command derives from <quote>caption</quote>, as it was previously only used to set the caption in an <acronym>HTML</acronym> table.) </para> </listitem> </varlistentry> <varlistentry> <term><literal>\connect</literal> (or <literal>\c</literal>) [ <replaceable class="parameter">dbname</replaceable> [ <replaceable class="parameter">username</replaceable> ] ]</term> <listitem> <para> Establishes a connection to a new database and/or under a user name. The previous connection is closed. If <replaceable class="parameter">dbname</replaceable> is <literal>-</literal> the current database name is assumed. </para> <para> If <replaceable class="parameter">username</replaceable> is omitted the current user name is assumed. </para> <para> As a special rule, <command>\connect</command> without any arguments will connect to the default database as the default user (as you would have gotten by starting <application>psql</application> without any arguments). </para> <para> If the connection attempt failed (wrong user name, access denied, etc.), the previous connection will be kept if and only if <application>psql</application> 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. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\copy <replaceable class="parameter">table</replaceable> [ ( <replaceable class="parameter">column_list</replaceable> ) ] { <literal>from</literal> | <literal>to</literal> } <replaceable class="parameter">filename</replaceable> | stdin | stdout [ <literal>with</literal> ] [ <literal>oids</literal> ] [ <literal>delimiter [as] </literal> '<replaceable class="parameter">character</replaceable>' ] [ <literal>null [as] </literal> '<replaceable class="parameter">string</replaceable>' ]</literal> </term> <listitem> <para> Performs a frontend (client) copy. This is an operation that runs an <acronym>SQL</acronym> <xref linkend="SQL-COPY" endterm="SQL-COPY-title"> command, but instead of the server reading or writing the specified file, <application>psql</application> reads or writes the file and routes the data between the server and the local file system. This means that file accessibility and privileges are those of the local user, not the server, and no SQL superuser privileges are required. </para> <para> The syntax of the command is similar to that of the <acronym>SQL</acronym> <command>COPY</command> command. (See its description for the details.) Note that, because of this, special parsing rules apply to the <command>\copy</command> command. In particular, the variable substitution rules and backslash escapes do not apply. </para> <tip> <para> This operation is not as efficient as the <acronym>SQL</acronym> <command>COPY</command> command because all data must pass through the client/server connection. For large amounts of data the other technique may be preferable. </para> </tip> <note> <para> Note the difference in interpretation of <literal>stdin</literal> and <literal>stdout</literal> between client and server copies: in a client copy these always refer to <application>psql</application>'s input and output stream. On a server copy <literal>stdin</literal> comes from wherever the <command>COPY</command> itself came from (for example, a script run with the <option>-f</option> option), and <literal>stdout</literal> refers to the query output stream (see <command>\o</command> meta-command below). </para> </note> </listitem> </varlistentry> <varlistentry> <term><literal>\copyright</literal></term> <listitem> <para> Shows the copyright and distribution terms of <application>PostgreSQL</application>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\d</literal> [ <replaceable class="parameter">pattern</replaceable> ]</term> <listitem> <para> For each relation (table, view, index, or sequence) matching the <replaceable class="parameter">pattern</replaceable>, show all columns, their types, and any special attributes such as <literal>NOT NULL</literal> or defaults, if any. Associated indexes, constraints, rules, and triggers are also shown, as is the view definition if the relation is a view. (<quote>Matching the pattern</> is defined below.) </para> <para> The command form <literal>\d+</literal> is identical, but any comments associated with the table columns are shown as well. </para> <note> <para> If <command>\d</command> is used without a <replaceable class="parameter">pattern</replaceable> argument, it is equivalent to <command>\dtvs</command> which will show a list of all tables, views, and sequences. This is purely a convenience measure. </para> </note> </listitem> </varlistentry> <varlistentry> <term><literal>\da</literal> [ <replaceable class="parameter">pattern</replaceable> ]</term> <listitem> <para> Lists all available aggregate functions, together with the data type they operate on. If <replaceable class="parameter">pattern</replaceable> is specified, only aggregates whose names match the pattern are shown. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\dc</literal> [ <replaceable class="parameter">pattern</replaceable> ]</term> <listitem> <para> Lists all available conversions between character-set encodings. If <replaceable class="parameter">pattern</replaceable> is specified, only conversions whose names match the pattern are listed. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\dC</literal></term> <listitem> <para> Lists all available type casts. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\dd</literal> [ <replaceable class="parameter">pattern</replaceable> ]</term> <listitem> <para> Shows the descriptions of objects matching the <replaceable class="parameter">pattern</replaceable>, or of all visible objects if no argument is given. But in either case, only objects that have a description are listed. (<quote>Object</quote> covers aggregates, functions, operators, types, relations (tables, views, indexes, sequences, large objects), rules, and triggers.) For example: <programlisting> => <userinput>\dd version</userinput> Object descriptions Schema | Name | Object | Description ------------+---------+----------+--------------------------- pg_catalog | version | function | PostgreSQL version string (1 row) </programlisting> </para> <para> Descriptions for objects can be created with the <command>COMMENT</command> <acronym>SQL</acronym> command. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\dD</literal> [ <replaceable class="parameter">pattern</replaceable> ]</term> <listitem> <para> Lists all available domains. If <replaceable class="parameter">pattern</replaceable> is specified, only matching domains are shown. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\df [ <replaceable class="parameter">pattern</replaceable> ]</literal></term> <listitem> <para> Lists available functions, together with their argument and return types. If <replaceable class="parameter">pattern</replaceable> is specified, only functions whose names match the pattern are shown. If the form <literal>\df+</literal> is used, additional information about each function, including language and description, is shown. </para> <note> <para> To reduce clutter, <literal>\df</> does not show data type I/O functions. This is implemented by ignoring functions that accept or return type <type>cstring</>. </para> </note> </listitem> </varlistentry> <varlistentry> <term><literal>\distvS [ <replaceable class="parameter">pattern</replaceable> ]</literal></term> <listitem> <para> 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 these letters, in any order, to obtain a listing of all the matching objects. The letter S restricts the listing to system objects; without S, only non-system objects are shown. If <literal>+</literal> is appended to the command name, each object is listed with its associated description, if any. </para> <para> If <replaceable class="parameter">pattern</replaceable> is specified, only objects whose names match the pattern are listed. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\dl</literal></term> <listitem> <para> This is an alias for <command>\lo_list</command>, which shows a list of large objects. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\dn</literal> [ <replaceable class="parameter">pattern</replaceable> ]</term> <listitem> <para> Lists all available schemas (namespaces). If <replaceable class="parameter">pattern</replaceable> (a regular expression) is specified, only schemas whose names match the pattern are listed. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\do [ <replaceable class="parameter">pattern</replaceable> ]</literal></term> <listitem> <para> Lists available operators with their operand and return types. If <replaceable class="parameter">pattern</replaceable> is specified, only operators whose names match the pattern are listed. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\dp</literal> [ <replaceable class="parameter">pattern</replaceable> ]</term> <listitem> <para> Produces a list of all available tables with their associated access privileges. If <replaceable class="parameter">pattern</replaceable> is specified, only tables whose names match the pattern are listed. </para> <para> The commands <xref linkend="SQL-GRANT"> and <xref linkend="SQL-REVOKE"> are used to set access privileges. See <xref linkend="SQL-GRANT"> for more information. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\dT [ <replaceable class="parameter">pattern</replaceable> ]</literal></term> <listitem> <para> Lists all data types or only those that match <replaceable class="parameter">pattern</replaceable>. The command form <literal>\dT+</literal> shows extra information. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\du [ <replaceable class="parameter">pattern</replaceable> ]</literal></term> <listitem> <para> Lists all database users or only those that match <replaceable class="parameter">pattern</replaceable>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\edit</literal> (or <literal>\e</literal>) [ <replaceable class="parameter">filename</replaceable> ]</term> <listitem> <para> If <replaceable class="parameter">filename</replaceable> is specified, the file is edited; after the editor exits, 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. </para> <para> The new query buffer is then re-parsed according to the normal rules of <application>psql</application>, where the whole buffer is treated as a single line. (Thus you cannot make scripts this way. Use <command>\i</command> 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. </para> <tip> <para> <application>psql</application> searches the environment variables <envar>PSQL_EDITOR</envar>, <envar>EDITOR</envar>, and <envar>VISUAL</envar> (in that order) for an editor to use. If all of them are unset, <filename>/bin/vi</filename> is run. </para> </tip> </listitem> </varlistentry> <varlistentry> <term><literal>\echo</literal> <replaceable class="parameter">text</replaceable> [ ... ]</term> <listitem> <para> Prints the arguments to the standard output, separated by one space and followed by a newline. This can be useful to intersperse information in the output of scripts. For example: <programlisting> => <userinput>\echo `date`</userinput> Tue Oct 26 21:40:57 CEST 1999 </programlisting> If the first argument is an unquoted <literal>-n</literal> the the trailing newline is not written. </para> <tip> <para> If you use the <command>\o</command> command to redirect your query output you may wish to use <command>\qecho</command> instead of this command. </para> </tip> </listitem> </varlistentry> <varlistentry> <term><literal>\encoding</literal> [ <replaceable class="parameter">encoding</replaceable> ]</term> <listitem> <para> Sets the client character set encoding. Without an argument, this command shows the current encoding. </para> <note> <para> This command will not notice changes made directly by <command>SET client_encoding</>. If you use <command>\encoding</command>, be sure to use it to set as well as examine the encoding. </para> </note> </listitem> </varlistentry> <varlistentry> <term><literal>\f</literal> [ <replaceable class="parameter">string</replaceable> ]</term> <listitem> <para> Sets the field separator for unaligned query output. The default is the vertical bar (<literal>|</literal>). See also <command>\pset</command> for a generic way of setting output options. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\g</literal> [ { <replaceable class="parameter">filename</replaceable> | <literal>|</literal><replaceable class="parameter">command</replaceable> } ]</term> <listitem> <para> Sends the current query input buffer to the server and optionally saves the output in <replaceable class="parameter">filename</replaceable> or pipes the output into a separate Unix shell to execute <replaceable class="parameter">command</replaceable>. A bare <literal>\g</literal> is virtually equivalent to a semicolon. A <literal>\g</literal> with argument is a <quote>one-shot</quote> alternative to the <command>\o</command> command. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\help</literal> (or <literal>\h</literal>) [ <replaceable class="parameter">command</replaceable> ]</term> <listitem> <para> Gives syntax help on the specified <acronym>SQL</acronym> command. If <replaceable class="parameter">command</replaceable> is not specified, then <application>psql</application> will list all the commands for which syntax help is available. If <replaceable class="parameter">command</replaceable> is an asterisk (<literal>*</literal>), then syntax help on all <acronym>SQL</acronym> commands is shown. </para> <note> <para> To simplify typing, commands that consists of several words do not have to be quoted. Thus it is fine to type <userinput>\help alter table</userinput>. </para> </note> </listitem> </varlistentry> <varlistentry> <term><literal>\H</literal></term> <listitem> <para> Turns on <acronym>HTML</acronym> query output format. If the <acronym>HTML</acronym> format is already on, it is switched back to the default aligned text format. This command is for compatibility and convenience, but see <command>\pset</command> about setting other output options. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\i</literal> <replaceable class="parameter">filename</replaceable></term> <listitem> <para> Reads input from the file <replaceable class="parameter">filename</replaceable> and executes it as though it had been typed on the keyboard. </para> <note> <para> If you want to see the lines on the screen as they are read you must set the variable <varname>ECHO</varname> to <literal>all</literal>. </para> </note> </listitem> </varlistentry> <varlistentry> <term><literal>\l</literal> (or <literal>\list</literal>)</term> <listitem> <para> List the names, owners, and character set encodings of all the databases in the server. Append a <literal>+</literal> to the command name to see any descriptions for the databases as well. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\lo_export</literal> <replaceable class="parameter">loid</replaceable> <replaceable class="parameter">filename</replaceable></term> <listitem> <para> Reads the large object with <acronym>OID</acronym> <replaceable class="parameter">loid</replaceable> from the database and writes it to <replaceable class="parameter">filename</replaceable>. Note that this is subtly different from the server function <function>lo_export</function>, which acts with the permissions of the user that the database server runs as and on the server's file system. </para> <tip> <para> Use <command>\lo_list</command> to find out the large object's <acronym>OID</acronym>. </para> </tip> </listitem> </varlistentry> <varlistentry> <term><literal>\lo_import</literal> <replaceable class="parameter">filename</replaceable> [ <replaceable class="parameter">comment</replaceable> ]</term> <listitem> <para> Stores the file into a <productname>PostgreSQL</productname> large object. Optionally, it associates the given comment with the object. Example: <programlisting> foo=> <userinput>\lo_import '/home/peter/pictures/photo.xcf' 'a picture of me'</userinput> lo_import 152801 </programlisting> 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 <command>\lo_list</command> command. </para> <para> Note that this command is subtly different from the server-side <function>lo_import</function> because it acts as the local user on the local file system, rather than the server's user and file system. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\lo_list</literal></term> <listitem> <para> Shows a list of all <productname>PostgreSQL</productname> large objects currently stored in the database, along with any comments provided for them. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\lo_unlink</literal> <replaceable class="parameter">loid</replaceable></term> <listitem> <para> Deletes the large object with <acronym>OID</acronym> <replaceable class="parameter">loid</replaceable> from the database. </para> <tip> <para> Use <command>\lo_list</command> to find out the large object's <acronym>OID</acronym>. </para> </tip> </listitem> </varlistentry> <varlistentry> <term><literal>\o</literal> [ {<replaceable class="parameter">filename</replaceable> | <literal>|</literal><replaceable class="parameter">command</replaceable>} ]</term> <listitem> <para> Saves future query results to the file <replaceable class="parameter">filename</replaceable> or pipes future results into a separate Unix shell to execute <replaceable class="parameter">command</replaceable>. If no arguments are specified, the query output will be reset to the standard output. </para> <para> <quote>Query results</quote> 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 <command>\d</command>), but not error messages. </para> <tip> <para> To intersperse text output in between query results, use <command>\qecho</command>. </para> </tip> </listitem> </varlistentry> <varlistentry> <term><literal>\p</literal></term> <listitem> <para> Print the current query buffer to the standard output. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\pset</literal> <replaceable class="parameter">parameter</replaceable> [ <replaceable class="parameter">value</replaceable> ]</term> <listitem> <para> This command sets options affecting the output of query result tables. <replaceable class="parameter">parameter</replaceable> describes which option is to be set. The semantics of <replaceable class="parameter">value</replaceable> depend thereon. </para> <para> Adjustable printing options are: <variablelist> <varlistentry> <term><literal>format</literal></term> <listitem> <para> Sets the output format to one of <literal>unaligned</literal>, <literal>aligned</literal>, <literal>html</literal>, or <literal>latex</literal>. Unique abbreviations are allowed. (That would mean one letter is enough.) </para> <para> <quote>Unaligned</quote> writes all columns of a row 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). <quote>Aligned</quote> mode is the standard, human-readable, nicely formatted text output that is default. The <quote><acronym>HTML</acronym></quote> and <quote>LaTeX</quote> 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 <acronym>HTML</acronym>, but in LaTeX you must have a complete document wrapper.) </para> </listitem> </varlistentry> <varlistentry> <term><literal>border</literal></term> <listitem> <para> 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 <acronym>HTML</acronym> mode, this will translate directly into the <literal>border=...</literal> attribute, in the others only values 0 (no border), 1 (internal dividing lines), and 2 (table frame) make sense. </para> </listitem> </varlistentry> <varlistentry> <term><literal>expanded</literal> (or <literal>x</literal>)</term> <listitem> <para> Toggles between regular and expanded format. When expanded format is enabled, all output has two columns with the column 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 <quote>horizontal</quote> mode. </para> <para> Expanded mode is supported by all four output formats. </para> </listitem> </varlistentry> <varlistentry> <term><literal>null</literal></term> <listitem> <para> The second argument is a string that should be printed whenever a column 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 <literal>\pset null '(null)'</literal>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>fieldsep</literal></term> <listitem> <para> 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 <literal>\pset fieldsep '\t'</literal>. The default field separator is <literal>'|'</literal> (a vertical bar). </para> </listitem> </varlistentry> <varlistentry> <term><literal>footer</literal></term> <listitem> <para> Toggles the display of the default footer <literal>(x rows)</literal>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>recordsep</literal></term> <listitem> <para> Specifies the record (line) separator to use in unaligned output mode. The default is a newline character. </para> </listitem> </varlistentry> <varlistentry> <term><literal>tuples_only</literal> (or <literal>t</literal>)</term> <listitem> <para> 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. </para> </listitem> </varlistentry> <varlistentry> <term><literal>title</literal> [ <replaceable class="parameter">text</replaceable> ]</term> <listitem> <para> 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. </para> </listitem> </varlistentry> <varlistentry> <term><literal>tableattr</literal> (or <literal>T</literal>) [ <replaceable class="parameter">text</replaceable> ]</term> <listitem> <para> Allows you to specify any attributes to be placed inside the <acronym>HTML</acronym> <sgmltag>table</sgmltag> tag. This could for example be <literal>cellpadding</literal> or <literal>bgcolor</literal>. Note that you probably don't want to specify <literal>border</literal> here, as that is already taken care of by <literal>\pset border</literal>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>pager</literal></term> <listitem> <para> Controls use of a pager for query and <application>psql</> help output. If the environment variable <envar>PAGER</envar> is set, the output is piped to the specified program. Otherwise a platform-dependent default (such as <filename>more</filename>) is used. </para> <para> When the pager is off, the pager is not used. When the pager is on, the pager is used only when appropriate, i.e. the output is to a terminal and will not fit on the screen. (<application>psql</> does not do a perfect job of estimating when to use the pager.) <literal>\pset pager</> turns the pager on and off. Pager can also be set to <literal>always</>, which causes the pager to be always used. </para> </listitem> </varlistentry> </variablelist> </para> <para> Illustrations on how these different formats look can be seen in the <xref linkend="APP-PSQL-examples" endterm="APP-PSQL-examples-title"> section. </para> <tip> <para> There are various shortcut commands for <command>\pset</command>. See <command>\a</command>, <command>\C</command>, <command>\H</command>, <command>\t</command>, <command>\T</command>, and <command>\x</command>. </para> </tip> <note> <para> It is an error to call <command>\pset</command> without arguments. In the future this call might show the current status of all printing options. </para> </note> </listitem> </varlistentry> <varlistentry> <term><literal>\q</literal></term> <listitem> <para> Quits the <application>psql</application> program. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\qecho</literal> <replaceable class="parameter">text</replaceable> [ ... ] </term> <listitem> <para> This command is identical to <command>\echo</command> except that all output will be written to the query output channel, as set by <command>\o</command>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\r</literal></term> <listitem> <para> Resets (clears) the query buffer. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\s</literal> [ <replaceable class="parameter">filename</replaceable> ]</term> <listitem> <para> Print or save the command line history to <replaceable class="parameter">filename</replaceable>. If <replaceable class="parameter">filename</replaceable> is omitted, the history is written to the standard output. This option is only available if <application>psql</application> is configured to use the <acronym>GNU</acronym> history library. </para> <note> <para> In the current version, 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 <application>psql</application> starts up. </para> </note> </listitem> </varlistentry> <varlistentry> <term><literal>\set</literal> [ <replaceable class="parameter">name</replaceable> [ <replaceable class="parameter">value</replaceable> [ ... ]]]</term> <listitem> <para> Sets the internal variable <replaceable class="parameter">name</replaceable> to <replaceable class="parameter">value</replaceable> or, if more than one value is given, to the concatenation of all of them. If no second argument is given, the variable is just set with no value. To unset a variable, use the <command>\unset</command> command. </para> <para> Valid variable names can contain characters, digits, and underscores. See the section <xref linkend="APP-PSQL-variables" endterm="APP-PSQL-variables-title"> below for details. </para> <para> Although you are welcome to set any variable to anything you want, <application>psql</application> treats several variables as special. They are documented in the section about variables. </para> <note> <para> This command is totally separate from the <acronym>SQL</acronym> command <xref linkend="SQL-SET" endterm="SQL-SET-title">. </para> </note> </listitem> </varlistentry> <varlistentry> <term><literal>\t</literal></term> <listitem> <para> Toggles the display of output column name headings and row count footer. This command is equivalent to <literal>\pset tuples_only</literal> and is provided for convenience. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\T</literal> <replaceable class="parameter">table_options</replaceable></term> <listitem> <para> Allows you to specify attributes to be placed within the <sgmltag>table</sgmltag> tag in <acronym>HTML</acronym> tabular output mode. This command is equivalent to <literal>\pset tableattr <replaceable class="parameter">table_options</replaceable></literal>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\timing</literal></term> <listitem> <para> Toggles a display of how long each SQL statement takes, in milliseconds. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\w</literal> {<replaceable class="parameter">filename</replaceable> | <replaceable class="parameter">|command</replaceable>}</term> <listitem> <para> Outputs the current query buffer to the file <replaceable class="parameter">filename</replaceable> or pipes it to the Unix command <replaceable class="parameter">command</replaceable>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\x</literal></term> <listitem> <para> Toggles extended table formatting mode. As such it is equivalent to <literal>\pset expanded</literal>. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\z</literal> [ <replaceable class="parameter">pattern</replaceable> ]</term> <listitem> <para> Produces a list of all available tables with their associated access privileges. If a <replaceable class="parameter">pattern</replaceable> is specified, only tables whose names match the pattern are listed. </para> <para> The commands <xref linkend="SQL-GRANT"> and <xref linkend="SQL-REVOKE"> are used to set access privileges. See <xref linkend="SQL-GRANT"> for more information. </para> <para> This is an alias for <command>\dp</command> (<quote>display privileges</quote>). </para> </listitem> </varlistentry> <varlistentry> <term><literal>\!</literal> [ <replaceable class="parameter">command</replaceable> ]</term> <listitem> <para> Escapes to a separate Unix shell or executes the Unix command <replaceable class="parameter">command</replaceable>. The arguments are not further interpreted, the shell will see them as is. </para> </listitem> </varlistentry> <varlistentry> <term><literal>\?</literal></term> <listitem> <para> Shows help information about the backslash commands. </para> </listitem> </varlistentry> </variablelist> </para> <para> The various <literal>\d</> commands accept a <replaceable class="parameter">pattern</replaceable> parameter to specify the object name(s) to be displayed. <literal>*</> means <quote>any sequence of characters</> and <literal>?</> means <quote>any single character</>. (This notation is comparable to Unix shell file name patterns.) Advanced users can also use regular-expression notations such as character classes, for example <literal>[0-9]</> to match <quote>any digit</>. To make any of these pattern-matching characters be interpreted literally, surround it with double quotes. </para> <para> A pattern that contains an (unquoted) dot is interpreted as a schema name pattern followed by an object name pattern. For example, <literal>\dt foo*.bar*</> displays all tables in schemas whose name starts with <literal>foo</> and whose table name starts with <literal>bar</>. If no dot appears, then the pattern matches only objects that are visible in the current schema search path. </para> <para> Whenever the <replaceable class="parameter">pattern</replaceable> parameter is omitted completely, the <literal>\d</> commands display all objects that are visible in the current schema search path. To see all objects in the database, use the pattern <literal>*.*</>. </para> </refsect2> <refsect2> <title>Advanced features</title> <refsect3 id="APP-PSQL-variables"> <title id="APP-PSQL-variables-title">Variables</title> <para> <application>psql</application> 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 <application>psql</application> meta-command <command>\set</command>: <programlisting> testdb=> <userinput>\set foo bar</userinput> </programlisting> sets the variable <literal>foo</literal> to the value <literal>bar</literal>. To retrieve the content of the variable, precede the name with a colon and use it as the argument of any slash command: <programlisting> testdb=> <userinput>\echo :foo</userinput> bar </programlisting> </para> <note> <para> The arguments of <command>\set</command> are subject to the same substitution rules as with other commands. Thus you can construct interesting references such as <literal>\set :foo 'something'</literal> and get <quote>soft links</quote> or <quote>variable variables</quote> of <productname>Perl</productname> or <productname><acronym>PHP</acronym></productname> fame, respectively. Unfortunately (or fortunately?), there is no way to do anything useful with these constructs. On the other hand, <literal>\set bar :foo</literal> is a perfectly valid way to copy a variable. </para> </note> <para> If you call <command>\set</command> without a second argument, the variable is set, with an empty string as value. To unset (or delete) a variable, use the command <command>\unset</command>. </para> <para> <application>psql</application>'s internal variable names can consist of letters, numbers, and underscores in any order and any number of them. A number of these variables are treated specially by <application>psql</application>. They indicate certain option settings that can be changed at run time 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 using such variable names for your own purposes. A list of all specially treated variables follows. </para> <variablelist> <varlistentry> <term><varname>AUTOCOMMIT</varname></term> <listitem> <para> When <literal>on</> (the default), each SQL command is automatically committed upon successful completion. To postpone commit in this mode, you must enter a <command>BEGIN</> or <command>START TRANSACTION</> SQL command. When <literal>off</> or unset, SQL commands are not committed until you explicitly issue <command>COMMIT</> or <command>END</>. The autocommit-off mode works by issuing an implicit <command>BEGIN</> for you, just before any command that is not already in a transaction block and is not itself a <command>BEGIN</> or other transaction-control command. </para> <note> <para> In autocommit-off mode, you must explicitly abandon any failed transaction by entering <command>ABORT</> or <command>ROLLBACK</>. Also keep in mind that if you exit the session without committing, your work will be lost. </para> </note> <note> <para> The autocommit-on mode is <productname>PostgreSQL</>'s traditional behavior, but autocommit-off is closer to the SQL spec. If you prefer autocommit-off, you may wish to set it in your <filename>.psqlrc</filename> file. </para> </note> </listitem> </varlistentry> <varlistentry> <term><varname>DBNAME</varname></term> <listitem> <para> The name of the database you are currently connected to. This is set every time you connect to a database (including program start-up), but can be unset. </para> </listitem> </varlistentry> <varlistentry> <term><varname>ECHO</varname></term> <listitem> <para> If set to <literal>all</literal>, all lines entered or from a script are written to the standard output before they are parsed or executed. To select this behavior on program start-up, use the switch <option>-a</option>. If set to <literal>queries</literal>, <application>psql</application> merely prints all queries as they are sent to the server. The switch for this is <option>-e</option>. </para> </listitem> </varlistentry> <varlistentry> <term><varname>ECHO_HIDDEN</varname></term> <listitem> <para> When this variable is set and a backslash command queries the database, the query is first shown. This way you can study the <productname>PostgreSQL</productname> internals and provide similar functionality in your own programs. (To select this behavior on program start-up, use the switch <option>-E</option>.) If you set the variable to the value <literal>noexec</literal>, the queries are just shown but are not actually sent to the server and executed. </para> </listitem> </varlistentry> <varlistentry> <term><varname>ENCODING</varname></term> <listitem> <para> The current client character set encoding. </para> </listitem> </varlistentry> <varlistentry> <term><varname>HISTCONTROL</varname></term> <listitem> <para> If this variable is set to <literal>ignorespace</literal>, lines which begin with a space are not entered into the history list. If set to a value of <literal>ignoredups</literal>, lines matching the previous history line are not entered. A value of <literal>ignoreboth</literal> combines the two options. If unset, or if set to any other value than those above, all lines read in interactive mode are saved on the history list. </para> <note> <para> This feature was shamelessly plagiarized from <application>Bash</application>. </para> </note> </listitem> </varlistentry> <varlistentry> <term><varname>HISTSIZE</varname></term> <listitem> <para> The number of commands to store in the command history. The default value is 500. </para> <note> <para> This feature was shamelessly plagiarized from <application>Bash</application>. </para> </note> </listitem> </varlistentry> <varlistentry> <term><varname>HOST</varname></term> <listitem> <para> The database server host you are currently connected to. This is set every time you connect to a database (including program start-up), but can be unset. </para> </listitem> </varlistentry> <varlistentry> <term><varname>IGNOREEOF</varname></term> <listitem> <para> If unset, sending an <acronym>EOF</> character (usually <keycombo action="simul"><keycap>Control</><keycap>D</></>) to an interactive session of <application>psql</application> will terminate the application. If set to a numeric value, that many <acronym>EOF</> characters are ignored before the application terminates. If the variable is set but has no numeric value, the default is 10. </para> <note> <para> This feature was shamelessly plagiarized from <application>Bash</application>. </para> </note> </listitem> </varlistentry> <varlistentry> <term><varname>LASTOID</varname></term> <listitem> <para> The value of the last affected OID, as returned from an <command>INSERT</command> or <command>lo_insert</command> command. This variable is only guaranteed to be valid until after the result of the next <acronym>SQL</acronym> command has been displayed. </para> </listitem> </varlistentry> <varlistentry> <term><varname>ON_ERROR_STOP</varname></term> <listitem> <para> By default, if non-interactive scripts encounter an error, such as a malformed <acronym>SQL</acronym> command or internal meta-command, processing continues. This has been the traditional behavior of <application>psql</application> but it is sometimes not 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 <application>psql</application> session but rather using the <option>-f</option> option, <application>psql</application> will return error code 3, to distinguish this case from fatal error conditions (error code 1). </para> </listitem> </varlistentry> <varlistentry> <term><varname>PORT</varname></term> <listitem> <para> The database server port to which you are currently connected. This is set every time you connect to a database (including program start-up), but can be unset. </para> </listitem> </varlistentry> <varlistentry> <term><varname>PROMPT1</varname></term> <term><varname>PROMPT2</varname></term> <term><varname>PROMPT3</varname></term> <listitem> <para> These specify what the prompts <application>psql</application> issues should look like. See <xref linkend="APP-PSQL-prompting" endterm="APP-PSQL-prompting-title"> below. </para> </listitem> </varlistentry> <varlistentry> <term><varname>QUIET</varname></term> <listitem> <para> This variable is equivalent to the command line option <option>-q</option>. It is probably not too useful in interactive mode. </para> </listitem> </varlistentry> <varlistentry> <term><varname>SINGLELINE</varname></term> <listitem> <para> This variable is equivalent to the command line option <option>-S</option>. </para> </listitem> </varlistentry> <varlistentry> <term><varname>SINGLESTEP</varname></term> <listitem> <para> This variable is equivalent to the command line option <option>-s</option>. </para> </listitem> </varlistentry> <varlistentry> <term><varname>USER</varname></term> <listitem> <para> The database user you are currently connected as. This is set every time you connect to a database (including program start-up), but can be unset. </para> </listitem> </varlistentry> <varlistentry> <term><varname>VERBOSE</varname></term> <listitem> <para> This variable can be set to the values <literal>default</>, <literal>verbose</>, or <literal>terse</> to control the verbosity of error reports. </para> </listitem> </varlistentry> <varlistentry> <term><varname>WIN32_CONSOLE</varname></term> <listitem> <para> This variable is only useful when working under the Win32 command console. As the Win32 command console uses a different encoding than the rest of the Windows system. Eight-bit characters (e.g. German Umlauts) are corrupted. When this variable is set the command console encoding will be translated into ASCII encoding for input and output. </para> </listitem> </varlistentry> </variablelist> </refsect3> <refsect3> <title><acronym>SQL</acronym> Interpolation</title> <para> An additional useful feature of <application>psql</application> variables is that you can substitute (<quote>interpolate</quote>) them into regular <acronym>SQL</acronym> statements. The syntax for this is again to prepend the variable name with a colon (<literal>:</literal>). <programlisting> testdb=> <userinput>\set foo 'my_table'</userinput> testdb=> <userinput>SELECT * FROM :foo;</userinput> </programlisting> would then query the table <literal>my_table</literal>. 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 <acronym>SQL</acronym> entities. </para> <para> A popular application of this facility is to refer to the last inserted <acronym>OID</acronym> 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 table column. First load the file into a variable and then proceed as above. <programlisting> testdb=> <userinput>\set content '\'' `cat my_file.txt` '\''</userinput> testdb=> <userinput>INSERT INTO my_table VALUES (:content);</userinput> </programlisting> One possible problem with this approach is that <filename>my_file.txt</filename> might contain single quotes. These need to be escaped so that they don't cause a syntax error when the second line is processed. This could be done with the program <command>sed</command>: <programlisting> testdb=> <userinput>\set content '\'' `sed -e "s/'/\\\\\\'/g" < my_file.txt` '\''</userinput> </programlisting> Observe the correct number of backslashes (6)! It works this way: After <application>psql</application> has parsed this line, it passes <literal>sed -e "s/'/\\\'/g" < my_file.txt</literal> to the shell. The shell will do its own thing inside the double quotes and execute <command>sed</command> with the arguments <literal>-e</literal> and <literal>s/'/\\'/g</literal>. When <command>sed</command> 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 <acronym>SQL</acronym> text constants are also subject to certain interpretations. In that case you might be better off preparing the file externally. </para> <para> Since colons may legally appear in SQL commands, the following rule applies: the character sequence <quote>:name</quote> is not changed unless <quote>name</> is the name of a variable that is currently set. In any case you can escape a colon with a backslash to protect it from substitution. (The colon syntax for variables is standard <acronym>SQL</acronym> for embedded query languages, such as <application>ECPG</application>. The colon syntax for array slices and type casts are <productname>PostgreSQL</productname> extensions, hence the conflict.) </para> </refsect3> <refsect3 id="APP-PSQL-prompting"> <title id="APP-PSQL-prompting-title">Prompting</title> <para> The prompts <application>psql</application> issues can be customized to your preference. The three variables <varname>PROMPT1</varname>, <varname>PROMPT2</varname>, and <varname>PROMPT3</varname> contain strings and special escape sequences that describe the appearance of the prompt. Prompt 1 is the normal prompt that is issued when <application>psql</application> requests a new command. Prompt 2 is issued when more input is expected during command input because the command was not terminated with a semicolon or a quote was not closed. Prompt 3 is issued when you run an <acronym>SQL</acronym> <command>COPY</command> command and you are expected to type in the row values on the terminal. </para> <para> The value of the selected prompt variable is printed literally, except where a percent sign (<literal>%</literal>) is encountered. Depending on the next character, certain other text is substituted instead. Defined substitutions are: <variablelist> <varlistentry> <term><literal>%M</literal></term> <listitem> <para> The full host name (with domain name) of the database server, or <literal>[local]</literal> if the connection is over a Unix domain socket, or <literal>[local:<replaceable>/dir/name</replaceable>]</literal >, if the Unix domain socket is not at the compiled in default location. </para> </listitem> </varlistentry> <varlistentry> <term><literal>%m</literal></term> <listitem> <para> The host name of the database server, truncated at the first dot, or <literal>[local]</literal> if the connection is over a Unix domain socket. </para> </listitem> </varlistentry> <varlistentry> <term><literal>%></literal></term> <listitem><para>The port number at which the database server is listening.</para></listitem> </varlistentry> <varlistentry> <term><literal>%n</literal></term> <listitem><para>The user name you are connected as (not your local system user name).</para></listitem> </varlistentry> <varlistentry> <term><literal>%/</literal></term> <listitem><para>The name of the current database.</para></listitem> </varlistentry> <varlistentry> <term><literal>%~</literal></term> <listitem><para>Like <literal>%/</literal>, but the output is <literal>~</literal> (tilde) if the database is your default database.</para></listitem> </varlistentry> <varlistentry> <term><literal>%#</literal></term> <listitem><para>If the current user is a database superuser, then a <literal>#</literal>, otherwise a <literal>></literal>.</para></listitem> </varlistentry> <varlistentry> <term><literal>%R</literal></term> <listitem> <para> In prompt 1 normally <literal>=</literal>, but <literal>^</literal> if in single-line mode, and <literal>!</literal> if the session is disconnected from the database (which can happen if <command>\connect</command> fails). In prompt 2 the sequence is replaced by <literal>-</literal>, <literal>*</literal>, a single quote, or a double quote, depending on whether <application>psql</application> expects more input because the command wasn't terminated yet, because you are inside a <literal>/* ... */</literal> comment, or because you are inside a quote. In prompt 3 the sequence doesn't produce anything. </para> </listitem> </varlistentry> <varlistentry> <term><literal>%T</literal></term> <listitem> <para> Transaction status: an empty string when not in a transaction block, or <literal>*</> when in a transaction block, or <literal>!</> when in a failed transaction block, or <literal>?</> when the transaction state is indeterminate (for example, because there is no connection). </para> </listitem> </varlistentry> <varlistentry> <term><literal>%</literal><replaceable class="parameter">digits</replaceable></term> <listitem> <para> The character with the indicated numeric code is substituted. If <replaceable class="parameter">digits</replaceable> starts with <literal>0x</literal> the rest of the characters are interpreted as hexadecimal; otherwise if the first digit is <literal>0</literal> the digits are interpreted as octal; otherwise the digits are read as a decimal number. </para> </listitem> </varlistentry> <varlistentry> <term><literal>%:</literal><replaceable class="parameter">name</replaceable><literal>:</literal></term> <listitem> <para> The value of the <application>psql</application> variable <replaceable class="parameter">name</replaceable>. See the section <xref linkend="APP-PSQL-variables" endterm="APP-PSQL-variables-title"> for details. </para> </listitem> </varlistentry> <varlistentry> <term><literal>%`</literal><replaceable class="parameter">command</replaceable><literal>`</literal></term> <listitem> <para> The output of <replaceable class="parameter">command</replaceable>, similar to ordinary <quote>back-tick</quote> substitution. </para> </listitem> </varlistentry> </variablelist> To insert a percent sign into your prompt, write <literal>%%</literal>. The default prompts are <literal>'%/%R%# '</literal> for prompts 1 and 2, and <literal>'>> '</literal> for prompt 3. </para> <note> <para> This feature was shamelessly plagiarized from <application>tcsh</application>. </para> </note> </refsect3> <refsect3> <title>Command-Line Editing</title> <para> <application>psql</application> supports the <application>Readline</application> library for convenient line editing and retrieval. The command history is stored in a file named <filename>.psql_history</filename> in your home directory and is reloaded when <application>psql</application> starts up. Tab-completion is also supported, although the completion logic makes no claim to be an <acronym>SQL</acronym> parser. If for some reason you do not like the tab completion, you can turn if off by putting this in a file named <filename>.inputrc</filename> in your home directory: <programlisting> $if psql set disable-completion on $endif </programlisting> (This is not a <application>psql</application> but a <application>Readline</application> feature. Read its documentation for further details.) </para> </refsect3> </refsect2> </refsect1> <refsect1> <title>Environment</title> <variablelist> <varlistentry> <term><envar>HOME</envar></term> <listitem> <para> Directory for initialization file (<filename>.psqlrc</filename>) and command history file (<filename>.psql_history</filename>). </para> </listitem> </varlistentry> <varlistentry> <term><envar>PAGER</envar></term> <listitem> <para> If the query results do not fit on the screen, they are piped through this command. Typical values are <literal>more</literal> or <literal>less</literal>. The default is platform-dependent. The use of the pager can be disabled by using the <command>\pset</command> command. </para> </listitem> </varlistentry> <varlistentry> <term><envar>PGDATABASE</envar></term> <listitem> <para> Default database to connect to </para> </listitem> </varlistentry> <varlistentry> <term><envar>PGHOST</envar></term> <term><envar>PGPORT</envar></term> <term><envar>PGUSER</envar></term> <listitem> <para> Default connection parameters </para> </listitem> </varlistentry> <varlistentry> <term><envar>PSQL_EDITOR</envar></term> <term><envar>EDITOR</envar></term> <term><envar>VISUAL</envar></term> <listitem> <para> Editor used by the <command>\e</command> command. The variables are examined in the order listed; the first that is set is used. </para> </listitem> </varlistentry> <varlistentry> <term><envar>SHELL</envar></term> <listitem> <para> Command executed by the <command>\!</command> command. </para> </listitem> </varlistentry> <varlistentry> <term><envar>TMPDIR</envar></term> <listitem> <para> Directory for storing temporary files. The default is <filename>/tmp</filename>. </para> </listitem> </varlistentry> </variablelist> </refsect1> <refsect1> <title>Files</title> <itemizedlist> <listitem> <para> Before starting up, <application>psql</application> attempts to read and execute commands from the file <filename>$HOME/.psqlrc</filename>. It could be used to set up the client or the server to taste (using the <command>\set </command> and <command>SET</command> commands). </para> </listitem> <listitem> <para> The command-line history is stored in the file <filename>$HOME/.psql_history</filename>. </para> </listitem> </itemizedlist> </refsect1> <refsect1> <title>Notes</title> <itemizedlist> <listitem> <para> In an earlier life <application>psql</application> allowed the first argument of a single-letter backslash command to start directly after the command, without intervening whitespace. For compatibility this is still supported to some extent, but were are not going to explain the details here as this use is discouraged. If you get strange messages, keep this in mind. For example <programlisting> testdb=> <userinput>\foo</userinput> Field separator is "oo". </programlisting> which is perhaps not what one would expect. </para> </listitem> <listitem> <para> <application>psql</application> only works smoothly with servers of the same version. That does not mean other combinations will fail outright, but subtle and not-so-subtle problems might come up. Backslash commands are particularly likely to fail if the server is of a different version. </para> </listitem> </itemizedlist> </refsect1> <refsect1 id="APP-PSQL-examples"> <title id="APP-PSQL-examples-title">Examples</title> <para> The first example shows how to spread a command over several lines of input. Notice the changing prompt: <programlisting> testdb=> <userinput>CREATE TABLE my_table (</userinput> testdb(> <userinput> first integer not null default 0,</userinput> testdb(> <userinput> second text</userinput> testdb-> <userinput>);</userinput> CREATE TABLE </programlisting> Now look at the table definition again: <programlisting> testdb=> <userinput>\d my_table</userinput> Table "my_table" Attribute | Type | Modifier -----------+---------+-------------------- first | integer | not null default 0 second | text | </programlisting> Now we change the prompt to something more interesting: <programlisting> testdb=> <userinput>\set PROMPT1 '%n@%m %~%R%# '</userinput> peter@localhost testdb=> </programlisting> Let's assume you have filled the table with data and want to take a look at it: <programlisting> peter@localhost testdb=> SELECT * FROM my_table; first | second -------+-------- 1 | one 2 | two 3 | three 4 | four (4 rows) </programlisting> You can make this table look differently by using the <command>\pset</command> command: <programlisting> peter@localhost testdb=> <userinput>\pset border 2</userinput> Border style is 2. peter@localhost testdb=> <userinput>SELECT * FROM my_table;</userinput> +-------+--------+ | first | second | +-------+--------+ | 1 | one | | 2 | two | | 3 | three | | 4 | four | +-------+--------+ (4 rows) peter@localhost testdb=> <userinput>\pset border 0</userinput> Border style is 0. peter@localhost testdb=> <userinput>SELECT * FROM my_table;</userinput> first second ----- ------ 1 one 2 two 3 three 4 four (4 rows) peter@localhost testdb=> <userinput>\pset border 1</userinput> Border style is 1. peter@localhost testdb=> <userinput>\pset format unaligned</userinput> Output format is unaligned. peter@localhost testdb=> <userinput>\pset fieldsep ","</userinput> Field separator is ",". peter@localhost testdb=> <userinput>\pset tuples_only</userinput> Showing only tuples. peter@localhost testdb=> <userinput>SELECT second, first FROM my_table;</userinput> one,1 two,2 three,3 four,4 </programlisting> Alternatively, use the short commands: <programlisting> peter@localhost testdb=> <userinput>\a \t \x</userinput> Output format is aligned. Tuples only is off. Expanded display is on. peter@localhost testdb=> <userinput>SELECT * FROM my_table;</userinput> -[ RECORD 1 ]- first | 1 second | one -[ RECORD 2 ]- first | 2 second | two -[ RECORD 3 ]- first | 3 second | three -[ RECORD 4 ]- first | 4 second | four </programlisting> </para> </refsect1> </refentry> <!-- Keep this comment at the end of the file Local variables: mode: sgml sgml-omittag:nil sgml-shorttag:t sgml-minimize-attributes:nil sgml-always-quote-attributes:t sgml-indent-step:1 sgml-indent-data:t sgml-parent-document:nil sgml-default-dtd-file:"../reference.ced" sgml-exposed-tags:nil sgml-local-catalogs:"/usr/lib/sgml/catalog" sgml-local-ecat-files:nil End: -->