If the gsql client is used to connect to a database, the connection timeout period will be 5 minutes. If the database has not correctly set up a connection and authenticated the identity of the client within this period, gsql will time out and exit.
To resolve this problem, see Troubleshooting.
Table 1 lists the advanced features of gsql.
Feature |
Description |
---|---|
Variable |
gsql provides a variable feature that is similar to the shell command of Linux. The following \set meta-command of gsql can be used to set a variable: \set varname value To delete a variable, run the following command: \unset varname NOTE:
For details about variable examples and descriptions, see Variable. |
SQL substitution |
Common SQL statements can be set to variables using the variable feature of gsql to simplify operations. For details about SQL substitution examples and descriptions, see Variable. |
Customized prompt |
Prompts of gsql can be customized. Prompts can be modified by changing the reserved variables of gsql: PROMPT1, PROMPT2, and PROMPT3. These variables can be set to customized values or the values predefined by gsql. For details, see Variable. |
Client operation history record |
gsql records client operation history. This function is enabled by specifying the -r parameter when a client is connected. The number of historical records can be set using the \set command. For example, \set HISTSIZE 50 indicates that the number of historical records is set to 50. \set HISTSIZE 0 indicates that the operation history is not recorded. NOTE:
|
1 | \set foo bar |
1 2 | \echo :foo bar |
This variable quotation method is suitable for regular SQL statements and meta-commands.
When the CLI parameter --dynamic-param (for details, see Table 1) is used or the special variable DYNAMIC_PARAM_ENABLE (for details, see Table 2) is set to true, you can execute the SQL statement to set the variable. The variable name is the column name in the SQL execution result and can be referenced using ${}. Example:
1 2 3 4 5 6 7 8 9 | \set DYNAMIC_PARAM_ENABLE true SELECT 'Jack' AS "Name"; Name ------ Jack (1 row) \echo ${Name} Jack |
In the preceding example, the SELECT statement is used to set the Name variable, and the ${} referencing method is used to obtain the value of the Name variable. In this example, the special variable DYNAMIC_PARAM_ENABLE controls this function. You can also use the CLI parameter --dynamic-param to control this function, for example, gsql -d postgres -p 25308 --dynamic-param -r.
Examples of setting variables by executing SQL statements:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 | \set DYNAMIC_PARAM_ENABLE true CREATE TABLE student (id INT, name VARCHAR(32)) DISTRIBUTE BY HASH(id); CREATE TABLE INSERT INTO student VALUES (1, 'Jack'), (2, 'Tom'), (3, 'Jerry'); INSERT 0 3 -- Do not set variables when the SQL statement execution fails. SELECT id, name FROM student ORDER BY idi; ERROR: column "idi" does not exist LINE 1: SELECT id, name FROM student ORDER BY idi; ^ \echo ${id} ${name} ${id} ${name} -- If the execution result contains multiple records, use specific characters to concatenate the values. SELECT id, name FROM student ORDER BY id; id | name ----+------- 1 | Jack 2 | Tom 3 | Jerry (3 rows) \echo ${id} ${name} 1,2,3 Jack,Tom,Jerry -- If the execution result contains only one record, execute the following statement to set the variable: SELECT id, name FROM student where id = 1; id | name ----+------ 1 | Jack (1 row) \echo ${id} ${name} 1 Jack -- If the execution result is empty, assign the variable with an empty string as follows: SELECT id, name FROM student where id = 4; id | name ----+------ (0 rows) \echo ${id} ${name} |
gsql pre-defines some special variables and plans the values of these variables. To ensure compatibility with later versions, do not use these variables for other purposes. For details about all special variables, see Table 2.
Variable |
Setting Method |
Description |
---|---|---|
DBNAME |
\set DBNAME dbname |
Specifies the name of a connected database. This variable is set again when a database is connected. |
ECHO |
\set ECHO all | queries |
|
ECHO_HIDDEN |
\set ECHO_HIDDEN on | off | noexec |
When a meta-command (such as \dg) is used to query database information, the value of this variable determines the query behavior.
|
ENCODING |
\set ENCODING encoding |
Specifies the character set encoding of the current client. |
FETCH_COUNT |
\set FETCH_COUNT variable |
NOTE:
Setting this variable to a proper value reduces memory usage. Generally, values from 100 to 1000 are proper. |
HISTCONTROL |
\set HISTCONTROL ignorespace | ignoredups | ignoreboth | none |
|
HISTFILE |
\set HISTFILE filename |
Specifies the file for storing historical records. The default value is ~/.bash_history. |
HISTSIZE |
\set HISTSIZE size |
Specifies the number of commands in the history command. The default value is 500. |
HOST |
\set HOST hostname |
Specifies the name of a connected host. |
IGNOREEOF |
\set IGNOREEOF variable |
|
LASTOID |
\set LASTOID oid |
Specifies the last OID, which is the value returned by an INSERT or lo_import command. This variable is valid only before the output of the next SQL statement is displayed. |
ON_ERROR_ROLLBACK |
\set ON_ERROR_ROLLBACK on | interactive | off |
|
ON_ERROR_STOP |
\set ON_ERROR_STOP on | off |
|
PORT |
\set PORT port |
Specifies the port number of a connected database. |
USER |
\set USER username |
Specifies the connected database user. |
VERBOSITY |
\set VERBOSITY terse | default | verbose |
This variable can be set to terse, default, or verbose to control redundant lines of error reports.
|
VAR_NOT_FOUND |
\set VAR_NOT_FOUND default | null | error |
You can set this parameter to default, null, or error to control the processing mode when the referenced variable does not exist.
|
VAR_MAX_LENGTH |
\set VAR_MAX_LENGTH variable |
Specifies the variable value length. The default value is 4096. If the length of a variable value exceeds the specified parameter value, the variable value is truncated and an alarm is generated. |
ERROR_LEVEL |
\set ERROR_LEVEL transaction | statement |
Indicates whether a transaction or statement is successful or not. Value options: transaction or statement. Default value: transaction
|
ERROR |
\set ERROR true | false |
Indicates whether the previous SQL statement is successfully executed or whether an error occurs during the execution of the previous transaction. false: succeeded. true: failed. default value: false The setting can be updated by executing SQL statements. You are not advised to manually set this parameter. |
LAST_ERROR_SQLSTATE |
\set LAST_ERROR_SQLSTATE state |
Error code of the previously failed SQL statement execution. The default value is 00000. The setting can be updated by executing SQL statements. You are not advised to manually set this parameter. |
LAST_ERROR_MESSAGE |
\set LAST_ERROR_MESSAGE message |
Error message of the previously failed SQL statement execution. The default value is an empty string. The setting can be updated by executing SQL statements. You are not advised to manually set this parameter. |
ROW_COUNT |
\set ROW_COUNT count |
If the SQL statement fails to be executed, set this parameter to 0. The default value is 0. The setting can be updated by executing SQL statements. You are not advised to manually set this parameter. |
SQLSTATE |
\set SQLSTATE state |
The default value is 00000. The setting can be updated by executing SQL statements. You are not advised to manually set this parameter. |
LAST_SYS_CODE |
\set LAST_SYS_CODE code |
Returned value of the previous system command execution. The default value is 0. The setting can be updated by using the meta-command \! to run the system command. You are not advised to manually set this parameter. |
DYNAMIC_PARAM_ENABLE |
\set DYNAMIC_PARAM_ENABLE true | false |
Controls the generation of variables and the variable referencing method ${} during SQL statement execution. The default value is false.
|
RESULT_DELIMITER |
\set RESULT_DELIMITER delimiter |
Controls the delimiter used for concatenating multiple records when variables are generated during SQL statement execution. The default delimiter is comma (,). |
COMPARE_STRATEGY |
\set COMPARE_STRATEGY default | natural | equal |
Used to control the value comparison policy of the \if expression. The default value is default.
For details, see \if conditional block comparison rules and examples. |
COMMAND_ERROR_STOP |
\set COMMAND_ERROR_STOP on | off |
Determines whether to report the error and stop executing the meta-command when an error occurs during meta-command execution. By default, the meta-command execution is not stopped. For details, see the COMMAND_ERROR_STOP example. |
1 2 3 4 5 6 7 8 9 10 11 | \set ERROR_LEVEL statement begin; BEGIN select 1 as ; ERROR: syntax error at or near ";" LINE 1: select 1 as ; ^ end; ROLLBACK \echo :ERROR false |
When ERROR_LEVEL is set to transaction, ERROR can be used to capture SQL execution errors in a transaction. In the following example, when a SQL execution error occurs in a transaction and the transaction ends, the value of ERROR is true.
1 2 3 4 5 6 7 8 9 10 11 | \set ERROR_LEVEL transaction begin; BEGIN select 1 as ; ERROR: syntax error at or near ";" LINE 1: select 1 as ; ^ end; ROLLBACK \echo :ERROR true |
When COMMAND_ERROR_STOP is set to on and an error occurs during the meta-command execution, the error is reported and the meta-command execution is stopped.
When COMMAND_ERROR_STOP is set to off and an error occurs during the meta-command execution, related information is printed and the script continues to be executed.
1 2 3 4 | \set COMMAND_ERROR_STOP on \i /home/omm/copy_data.sql select id, name from student; |
When COMMAND_ERROR_STOP in the preceding script is set to on, an error message is displayed after the meta-command reports an error, and the script execution is stopped.
1 | gsql:test.sql:2: /home/omm/copy_data.sql: Not a directory |
When COMMAND_ERROR_STOP is set to off, an error message is displayed after the meta-command reports an error, and the SELECT statement continues to be executed.
1 2 3 4 5 | gsql:test.sql:2: /home/omm/copy_data.sql: Not a directory id | name ----+------ 1 | Jack (1 row) |
1 2 3 4 5 6 7 8 9 | \set foo 'HR.areaS' select * from :foo; area_id | area_name ---------+------------------------ 4 | Iron 3 | Desert 1 | Wood 2 | Lake (4 rows) |
The above command queries the HR.areaS table.
The value of a variable is copied character by character, and even an asymmetric quote mark or backslash (\) is copied. Therefore, the input content must be meaningful.
The gsql prompt can be set using the three variables in Table 3. These variables consist of characters and special escape characters.
Variable |
Description |
Example |
||||||
---|---|---|---|---|---|---|---|---|
PROMPT1 |
Specifies the normal prompt used when gsql requests a new command. The default value of PROMPT1 is: %/%R%# |
PROMPT1 can be used to change the prompt.
|
||||||
PROMPT2 |
Specifies the prompt displayed when more command input is expected. For example, it is expected if a command is not terminated with a semicolon (;) or a quote (") is not closed. |
PROMPT2 can be used to display the prompt:
|
||||||
PROMPT3 |
Specifies the prompt displayed when the COPY statement (such as COPY FROM STDIN) is run and data input is expected. |
PROMPT3 can be used to display the COPY prompt.
|
The value of the selected prompt variable is printed literally. However, a value containing a percent sign (%) is replaced by the predefined contents depending on the character following the percent sign (%). For details about the defined substitutions, see Table 4.
Symbol |
Description |
---|---|
%M |
Specifies the full host name (with domain name). The full name is [local] if the connection is over a Unix domain socket, or [local:/dir/name] if the Unix domain socket is not at the compiled default location. |
%m |
Specifies the host name truncated at the first dot. It is [local] if the connection is over a Unix domain socket. |
%> |
Specifies the number of the port that the host is listening on. |
%n |
Specifies the database session user name. |
%/ |
Specifies the name of the current database. |
%~ |
Is similar to %/. However, the output is tilde (~) if the database is your default database. |
%# |
Uses # if the session user is the database administrator. Otherwise, uses >. |
%R |
|
%x |
Specifies the transaction status.
|
%digits |
Is replaced with the character with the specified byte. |
%:name |
Specifies the value of the name variable of gsql. |
%command |
Specifies command output, similar to ordinary "back-tick" ("^") substitution. |
%[ . . . %] |
Prompts can contain terminal control characters which, for example, change the color, background, or style of the prompt text, or change the title of the terminal window. For example: potgres=> \set PROMPT1 '%[%033[1;33;40m%]%n@%/%R%[%033[0m%]%#' The output is a boldfaced (1;) yellow-on-black (33;40) prompt on VT100-compatible, color-capable terminals. |
Name |
Description |
---|---|
COLUMNS |
If \set columns is set to 0, this parameter controls the width of the wrapped format. This width determines whether the width output mode is changed to a vertical bar format in automatic expansion mode. |
PAGER |
If the query result cannot be displayed within one page, the query result will be redirected to the command. You can use the \pset command to disable the pager. Typically, the more or less command is used for viewing the query result page by page. The default value is platform-associated. NOTE:
Display of the less command is affected by the LC_CTYPE environmental variable. |
PSQL_EDITOR |
The \e and \ef commands use the editor specified by the environment variables. Variables are checked according to the list sequence. The default editor on Unix is vi. |
EDITOR |
|
VISUAL |
|
PSQL_EDITOR_LINENUMBER_ARG |
When the \e or \ef command is used with a line number parameter, this variable specifies the command-line parameter used to pass the starting line number to the editor. For editors, such as Emacs or vi, this is a plus sign. A space is added behind the value of the variable if whitespace is required between the option name and the line number. For example:
PSQL_EDITOR_LINENUMBER_ARG = '+' PSQL_EDITOR_LINENUMBER_ARG='--line ' A plus sign (+) is used by default on Unix. |
PSQLRC |
Specifies the location of the user's .gsqlrc file. |
SHELL |
Has the same effect as the \! command. |
TMPDIR |
Specifies the directory for storing temporary files. The default value is /tmp. |