gsql
gsql is a database connection tool provided by openGauss and runs in the command-line interface (CLI). Users can use gsql to connect to a server and perform operations and maintenance on the server. In addition to basic functions for performing operations on a database, gsql provides several advanced features for users.
Overview
Basic Features
Connect to the database: For details, see Gsql Connection and Usage.
NOTE:
If the gsql client is used to connect to a database, the connection timeout period will be 5 minutes by default. 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 FAQs.
Run SQL statements: Interactively entered SQL statements and specified SQL statements in a file can be run.
Run meta-commands: Meta-commands help the administrator view database object information, query cache information, format SQL output, and connect to a new database. For details about meta-commands, see Meta-Command Reference.
Advanced Features
Table 1 lists the advanced features of gsql.
Table 1 Advanced features of gsql
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 variables. | |
Common SQL statements can be set to variables using the variable feature of gsql to simplify operations. For details about examples and descriptions about SQL substitution, see SQL substitution. | |
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 Prompt. | |
According to the openGauss syntax rules, gsql supports automatic command completion by pressing Tab. This function is enabled when the --with-readline option is specified during compilation and the -r parameter is specified during client connection. For example, if you enter crea and then press Tab, gsql will change it to create. Note:
| |
gsql can record historical client operations. 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:
|
To set a variable, run the \set meta-command of gsql. For example, to set variable foo to bar, run the following command:
postgres=# \set foo bar
To reference the value of a variable, add a colon (:) before the variable. For example, to view the value of variable foo, run the following command:
postgres=# \echo :foo bar
The variable reference method is suitable for regular SQL statements and meta-commands.
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 special variables, see Table 2.
NOTE:
- All the special variables consist of upper-case letters, digits, and underscores(_).
- To view the default value of a special variable, run the \echo :varname meta-command, for example, \echo :DBNAME.
Table 2 Settings of special variables
gsql, like a parameter of a meta-command, provides a key feature that enables you to substitute a standard SQL statement for a gsql variable. gsql also provides a new alias or identifier for the variable. To replace the value of a variable using the SQL substitution method, add a colon (:) before the variable. For example:
postgres=# \set foo 'HR.areaS' postgres=# select * from :foo; area_id | area_name ---------+------------------------ 4 | Middle East and Africa 3 | Asia 1 | Europe 2 | Americas (4 rows)
The above command queries the HR.areaS table.
NOTICE: The value of the variable is copied literally, so it can even contain unbalanced quotation marks or backslash commands. 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.
Table 3 Prompt variables
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.
Table 4 Defined substitutions
Environment Variables
Table 5 Environment variables related to gsql
Usage Guidelines
Prerequisites
The user has the permission to access the database.
Background
Use the gsql command to connect to the remote database service. When connecting to the remote database service, enable remote connection on the server. For details, see Gsql Connection and Usage.
Procedure
Connect to the openGauss server using the gsql tool.
The gsql tool uses the -d parameter to specify the target database name, the -U parameter to specify the database username, the -h parameter to specify the host name, and the -p parameter to specify the port number.
NOTE:
- If the database name is not specified, the default database name generated during initialization is used.
- If the database user name is not specified, the current OS user is used as the database user name by default.
- If a value does not contain a parameter (such as -d or -U) and the database name (-d) is not specified in the connection command, the parameter is interpreted as the database name.
- If the database name (-d) is specified but the database user name (-U) is not specified, this parameter is interpreted as the database user name.
Example 1: Connect to port 15400 of the postgres database on the local PC as user omm:
gsql -d postgres -p 15400
Example 2: Connect to the port 15400 of the remote postgres database as user jack.
gsql -h 10.180.123.163 -d postgres -U jack -p 15400
Example 3: postgres and omm do not belong to any parameter, and they are used as the database name and the username, respectively.
gsql postgres omm -p 15400
Equals
gsql -d postgres -U omm -p 15400
For details about the gsql parameters, see Command Reference.
Run a SQL statement.
The following takes creating database human_staff as an example:
CREATE DATABASE human_staff;
Ordinarily, input lines end when a command-terminating semicolon is reached. If the command is sent and executed without any error, the command output is displayed on the screen.
Execute gsql meta-commands.
The following takes the listing of all openGauss databases and description information as an example.
ostgres=# \l List of databases Name | Owner | Encoding | Collate | Ctype | Access privileges ----------------+----------+-----------+---------+-------+----------------------- human_resource | omm | SQL_ASCII | C | C | postgres | omm | SQL_ASCII | C | C | template0 | omm | SQL_ASCII | C | C | =c/omm + | | | | | omm=CTc/omm template1 | omm | SQL_ASCII | C | C | =c/omm + | | | | | omm=CTc/omm human_staff | omm | SQL_ASCII | C | C | (5 rows)
For details about gsql meta-commands, see Meta-Command Reference .
Example
Run the following command to create a tablespace EXAMPLE:
postgres=# CREATE TABLESPACE EXAMPLE RELATIVE LOCATION 'tablespace1/tablespace_1';
CREATE TABLESPACE
After the tablespace is created, run the following command to create a schema HR:
postgres=# CREATE schema HR;
CREATE SCHEMA
The example shows how to spread a command over several lines of input. Note the prompt change:
postgres=# CREATE TABLE HR.areaS(
postgres(# area_ID NUMBER,
postgres(# area_NAME VARCHAR2(25)
postgres(# )tablespace EXAMPLE;
CREATE TABLE
Query the table definition:
postgres=# \d HR.areaS
Table "hr.areas"
Column | Type | Modifiers
-----------+-----------------------+-----------
area_id | numeric |
area_name | character varying(25) |
Tablespace: "example"
Insert four lines of data into HR.areaS.
postgres=# INSERT INTO HR.areaS (area_ID, area_NAME) VALUES (1, 'Europe');
INSERT 0 1
postgres=# INSERT INTO HR.areaS (area_ID, area_NAME) VALUES (2, 'Americas');
INSERT 0 1
postgres=# INSERT INTO HR.areaS (area_ID, area_NAME) VALUES (3, 'Asia');
INSERT 0 1
postgres=# INSERT INTO HR.areaS (area_ID, area_NAME) VALUES (4, 'Middle East and Africa');
INSERT 0 1
Change the prompt.
postgres=# \set PROMPT1 '%n@%m %~%R%#'
omm@[local] postgres=#
Query the table:
omm@[local] postgres=#SELECT * FROM HR.areaS;
area_id | area_name
---------+------------------------
1 | Europe
4 | Middle East and Africa
2 | Americas
3 | Asia
(4 rows)
Use the \pset command to display the table in different ways:
omm@[local] postgres=#\pset border 2
Border style is 2.
omm@[local] postgres=#SELECT * FROM HR.areaS;
+---------+------------------------+
| area_id | area_name |
+---------+------------------------+
| 1 | Europe |
| 2 | Americas |
| 3 | Asia |
| 4 | Middle East and Africa |
+---------+------------------------+
(4 rows)
omm@[local] postgres=#\pset border 0
Border style is 0.
omm@[local] postgres=#SELECT * FROM HR.areaS;
area_id area_name
------- ----------------------
1 Europe
2 Americas
3 Asia
4 Middle East and Africa
(4 rows)
omm@[local] postgres=#\pset border 2
Border style is 2.
omm@[local] postgres=#SELECT * FROM HR.areaS;
+---------+------------------------+
| area_id | area_name |
+---------+------------------------+
| 1 | Europe |
| 2 | Americas |
| 3 | Asia |
| 4 | Middle East and Africa |
+---------+------------------------+
(4 rows)
omm@[local] postgres=#\pset border 0
Border style is 0.
omm@[local] postgres=#SELECT * FROM HR.areaS;
area_id area_name
------- ----------------------
1 Europe
2 Americas
3 Asia
4 Middle East and Africa
(4 rows)
omm@[local] postgres=#\pset border 2
Border style is 2.
omm@[local] postgres=#SELECT * FROM HR.areaS;
+---------+------------------------+
| area_id | area_name |
+---------+------------------------+
| 1 | Europe |
| 2 | Americas |
| 3 | Asia |
| 4 | Middle East and Africa |
+---------+------------------------+
(4 rows)
omm@[local] postgres=#\pset border 0
Border style is 0.
omm@[local] postgres=#SELECT * FROM HR.areaS;
area_id area_name
------- ----------------------
1 Europe
2 Americas
3 Asia
4 Middle East and Africa
(4 rows)
Use the meta-command:
omm@[local] postgres=#\a \t \x
Output format is unaligned.
Showing only tuples.
Expanded display is on.
omm@[local] postgres=#SELECT * FROM HR.areaS;
area_id|2
area_name|Americas
area_id|1
area_name|Europe
area_id|4
area_name|Middle East and Africa
area_id|3
area_name|Asia
omm@[local] postgres=#
Obtaining Help Information
Procedure
After connecting to the database, run the following command to obtain the help information:
gsql --help
The following help information is displayed:
...... Usage: gsql [OPTION]... [DBNAME [USERNAME]] General options: -c, --command=COMMAND run only single command (SQL or internal) and exit -d, --dbname=DBNAME database name to connect to (default: "omm") -f, --file=FILENAME execute commands from file, then exit ......
After connecting to the database, run the following command to obtain the help information:
help
The following help information is displayed:
You are using gsql, the command-line interface to gaussdb. Type: \copyright for distribution terms \h for help with SQL commands \? for help with gsql commands \g or terminate with semicolon to execute query \q to quit
Examples
Run the following command to connect to the database:
gsql -d postgres -p 15400
postgres is the name of the database to be connected, and 15400 is the port number of the primary database node.
If information similar to the following is displayed, the connection succeeds:
gsql ((openGauss x.x build 290d125f) compiled at 2020-05-08 02:59:43 commit 2143 last mr 131 Non-SSL connection (SSL connection is recommended when requiring high-security) Type "help" for help. postgres=#
View the gsql help information. For details, see Table gsql online help.
Table 6 gsql online help
Command Reference
For details about gsql parameters, see Table Common parameters, Table Input and output parameters, Table Output format parameters, and Table Connection parameters.
Table 7 Common parameters
Specifies that gsql is to run a string command and then exit. | ||
Specifies the name of the database to connect to. In addition, gsql allows you to use extended database names, that is, connection strings in the format of 'postgres[ql]://[user[:password]@][netloc][:port][, ...][/dbname][?param1=value1&...]' or '[key=value] [...]' as database names. gsql parses connection information from the connection strings and preferentially uses the information. | ||
Specifies that files are used as the command source instead of interactively-entered commands. After the files are processed, gsql exits. If FILENAME is - (hyphen), then standard input is read. NOTE: Environment scenario: one primary and one standby (8 CPUs and 32 GB memory) Test result: It takes about 8 minutes and 21 seconds to read a 200 MB data file. It takes about 18 minutes and 41 seconds to read a 500 MB data file. Suggestion: The file read time increases with the file data volume. If the file size is too large, the file needs to be read again when an exception occurs. In addition, the I/O of the system OS will be overloaded. It is recommended that the file size be about 500 MB. | An absolute path or relative path that meets the OS path naming convention | |
For details about variable examples and descriptions, see variables. | ||
Does not read the startup file (neither the system-wide gsqlrc file nor the user's ~/.gsqlrc file). | ||
When gsql uses the -f parameter to execute a script, START TRANSACTION and COMMIT are added to the start and end of the script, respectively, so that the script is executed as one transaction. This ensures that the script is executed successfully. If the script cannot be executed, the script is invalid. | ||
Displays help information about gsql command parameters, and exits. | ||
Table 8 Input and output parameters
Table 9 Output format parameters
Table 10 Connection parameters
Meta-Command Reference
This section describes meta-commands provided by gsql after the openGauss database CLI tool is used to connect to a database. A gsql meta-command can be anything that you enter in gsql and begins with an unquoted backslash.
Precautions
The format of the gsql meta-command is a backslash (\) followed by a command verb, and then a parameter. The parameters are separated from the command verb and from each other by any number of whitespace characters.
To include whitespace in a parameter, you can quote it with single quotation marks (''). To include single quotation marks in a parameter, add a backslash in front of it. Anything contained in single quotation marks is furthermore subject to C-like substitutions for \n (new line), \t (tab), \b (backspace), \r (carriage return), \f (form feed), \digits (octal), and \xdigits (hexadecimal).
Within a parameter, text enclosed in double quotation marks ("") is taken as a command line input to the shell. The command output (with any trailing newline removed) is taken as a parameter.
If an unquoted parameter begins with a colon (:), the parameter is taken as a gsql variable and the value of the variable is used as the parameter value instead.
Some commands take an SQL identifier (such as a table name) as a parameter. These parameters follow the SQL syntax rules: Unquoted letters are forced to lowercase, while double quotation marks ("") protect letters from case conversion and allow incorporation of whitespace into the identifier. Within double quotation marks, paired double quotation marks reduce to a single double quotation mark in the result name. For example, FOO"BAR"BAZ is interpreted as fooBARbaz, and “Aweird"“name” becomes A weird"name.
Parameter parsing stops when another unquoted backslash appears. An unquoted backslash is taken as the beginning of a new meta-command. The special sequence \\ (two backslashes) marks the end of parameters and continues parsing SQL statements if any. In this way, SQL statements and gsql commands can be freely mixed in a line. However, the parameters of a meta-command cannot continue beyond the end of a line in any situations.
Meta-Commands
For details about meta-commands, see Table Common meta-commands, Table Query buffer meta-commands, Table Input and output meta-commands, Table Information display meta-commands, Table Formatting meta-commands,Table Connection meta-commands , Table OS meta-commands, Table Variable meta-commands, and Table Large object meta-commands.
NOTICE:
FILE mentioned in the following commands indicates a file path. This path can be an absolute path such as /home/gauss/file.txt or a relative path, such as file.txt. By default, a file.txt is created in the path where the user runs gsql commands.
Table 11 Common meta-commands
Table 12 Query buffer meta-commands
Uses an external editor to edit the function definition. If LINE is specified, the cursor will point to the specified line of the function body. | |
Table 13 Input and output meta-commands
NOTE: In Table 14, option S indicates displaying the system object and PATTERN indicates displaying the additional description information and the name of the object to be displayed.
Table 14 Information display meta-commands
Lists all tables, views, and sequences of all schemas in search_path. When objects with the same name exist in different schemas in search_path, only the object in the schema that ranks first in search_path is displayed. | List all tables, views, and sequences of all schemas in search_path. openGauss=# \d | ||
Lists the structure of specified tables, views, and indexes. | List the structure of table a. openGauss=# \dtable+ a | ||
If PATTERN is specified, only tables, views, and indexes whose names match PATTERN are displayed. | List all tables, views, and indexes whose names start with f. openGauss=# \d+ f* | ||
Lists all available aggregate functions, together with their return value types and the data types. | If PATTERN is specified, only aggregate functions whose names match PATTERN are displayed. | List all available aggregate functions whose names start with f, together with their return value types and the data types. openGauss=# \da f* | |
If PATTERN is specified, only tablespaces whose names match PATTERN are displayed. | List all available tablespaces whose names start with p. openGauss=# \db p* | ||
If PATTERN is specified, only conversions whose names match PATTERN are displayed. | List all available conversions between character sets. openGauss=# \dc * | ||
If PATTERN is specified, only conversions whose names match PATTERN are displayed. | List all type conversion whose patten names start with c. openGauss=# \dC c* | ||
If PATTERN is not specified, all visible objects are displayed. The objects include aggregations, functions, operators, types, relations (table, view, index, sequence, and large object), and rules. | openGauss=# \dd | ||
If PATTERN is specified, only permissions whose names match PATTERN are displayed. | openGauss=# \ddp | ||
If PATTERN is specified, only domains whose names match PATTERN are displayed. | openGauss=# \dD | ||
If PATTERN is specified, only objects whose names match PATTERN are displayed. | openGauss=# \ded | ||
If PATTERN is specified, only tables whose names match PATTERN are displayed. | openGauss=# \det | ||
If PATTERN is specified, only servers whose names match PATTERN are displayed. | openGauss=# \des | ||
If PATTERN is specified, only mappings whose names match PATTERN are displayed. | openGauss=# \deu | ||
If PATTERN is specified, only wrappers whose names match PATTERN are displayed. | openGauss=# \dew | ||
Lists all available functions, together with their parameters and return types. a indicates an aggregate function, n indicates a common function, t indicates a trigger, and w indicates a window function. | If PATTERN is specified, only functions whose names match PATTERN are displayed. | Lists all available functions, together with their parameters and return types. openGauss=# \df | |
If PATTERN is specified, only configurations whose names match PATTERN are displayed. | List all text search configurations. openGauss=# \dF+ | ||
If PATTERN is specified, only dictionaries whose names match PATTERN are displayed. | List all text search dictionaries. openGauss=# \dFd | ||
If PATTERN is specified, only parsers whose names match PATTERN are displayed. | openGauss=# \dFp | ||
If PATTERN is specified, only templates whose names match PATTERN are displayed. | List all text search templates. openGauss=# \dFt | ||
If PATTERN is specified, only roles whose names match PATTERN are displayed. | List all database roles whose names start with j and end with e. openGauss=# \dg j?e | ||
openGauss=# \dl | |||
If PATTERN is specified, only languages whose names match PATTERN are displayed. | List available procedural languages. openGauss=# \dL | ||
If PATTERN is specified, only materialized views whose names match PATTERN are displayed. | openGauss=# \dm | ||
If PATTERN is specified, only schemas whose names match PATTERN are displayed. By default, only schemas you created are displayed. | List information about all schemas whose names start with d. openGauss=# \dn+ d* | ||
Lists all available operators with their operand and return types. | If PATTERN is specified, only operators whose names match PATTERN are displayed. By default, only operators you created are displayed. | List all available operators with their operand and return types. openGauss=# \do | |
If PATTERN is specified, only collations whose names match PATTERN are displayed. By default, only collations you created are displayed. | openGauss=# \dO | ||
Lists tables, views, and related permissions. The following result about \dp is displayed: rolename=xxxx/yyyy --Assigning permissions to a role =xxxx/yyyy --Assigning permissions to public xxxx indicates assigned permissions, and yyyy indicates roles with the assigned permissions. For details about permission descriptions, see Table Description of permissions. | If PATTERN is specified, only tables and views whose names match PATTERN are displayed. | List tables, views, and related permissions. openGauss=# \dp | |
Lists all modified configuration parameters. These settings can be for roles, for databases, or for both. PATTERN1 and PATTERN2 indicate a role pattern and a database pattern, respectively. | If PATTERN is specified, only collations whose names match PATTERN are displayed. If the default value is used or * is specified, all settings are listed. | List all modified configuration parameters of the postgres database. openGauss=# \drds * postgres | |
If PATTERN is specified, only types whose names match PATTERN are displayed. | openGauss=# \dT | ||
If PATTERN is specified, only roles whose names match PATTERN are displayed. | openGauss=# \du | ||
In this group of commands, the letters E, i, s, t, and v stand for a foreign table, index, sequence, table, or view, respectively. You can specify any or a combination of these letters sequenced in any order to obtain an object list. For example, \dit lists all indexes and tables. If a command is suffixed with a plus sign (+), physical dimensions and related descriptions of each object will be displayed. | If PATTERN is specified, only objects whose names match PATTERN are displayed. By default, only objects you created are displayed. You can specify PATTERN or S to view other system objects. | openGauss=# \div | |
If PATTERN is specified, only extensions whose names match PATTERN are displayed. | List the extensions of the installed database. openGauss=# \dx | ||
Lists the names, owners, character set encodings, and permissions of all the databases on the server. | List the names, owners, character set encodings, and permissions of all the databases on the server. openGauss=# \l | ||
Assume a function function_a and a function func()name. This parameter will be as follows: openGauss=# \sf function_a openGauss=# \sf "func()name"(argtype1, argtype2) | |||
Lists all tables, views, and sequences in the database and their access permissions. | If a pattern is given, it is a regular expression, and only matched tables, views, and sequences are displayed. | List all tables, views, and sequences in the database and their access permissions. openGauss=# \z |
Table 15 Description of permissions
Table 16 Formatting meta-commands
Controls the switchover between unaligned mode and aligned mode. | |
Sets the title of any table being printed as the result of a query or cancels such a setting. | |
| |
Sets options affecting the output of query result tables. For details about the value of NAME, see Table Adjustable printing options. | |
Switches the information and row count footer of the output column name. | |
Specifies attributes to be placed within the table tag in HTML output format. If the parameter is not configured, the attributes are not set. | |
Table 17 Adjustable printing options
Table 18 Connection meta-commands
Table 19 OS meta-commands
Table 20 Variable meta-commands
Sets the NAME internal variable to VALUE. If more than one value is provided, NAME is set to the concatenation of all of them. If only one parameter is provided, the variable is set with an empty value. Some common variables are processed in another way in gsql, and they are the combination of uppercase letters, numbers, and underscores. Table 21 describes a list of variables that are processed in a way different from other variables. | |
Table 21 Common \set commands
Table 22 Large object meta-commands
Displays a list of all openGauss large objects stored in the database, along with comments provided for them. |
PATTERN
The various \d commands accept a PATTERN parameter to specify the object name to be displayed. In the simplest case, a pattern is just the exact name of the object. The characters within a pattern are normally folded to lower case, similar to those in SQL names. For example, \dt FOO will display the table named foo. As in SQL names, placing double quotation marks (”) around a pattern prevents them being folded to lower case. If you need to include a double quotation mark (") in a pattern, write it as a pair of double quotation marks ("") within a double-quote sequence, which is in accordance with the rules for SQL quoted identifiers. For example, \dt “FOO"“BAR” will be displayed as a table named FOO"BAR instead of foo"bar. You cannot put double quotation marks around just part of a pattern, which is different from the normal rules for SQL names. For example, \dt FOO"FOO"BAR will be displayed as a table named fooFOObar if just part of a pattern is quoted.
Whenever the PATTERN parameter is omitted completely, the \d commands display all objects that are visible in the current schema search path, which is equivalent to using an asterisk (*) as the pattern. An object is regarded to be visible if it can be referenced by name without explicit schema qualification. To see all objects in the database regardless of their visibility, use a dot within double asterisks (*.*) as the pattern.
Within a pattern, the asterisk (*) matches any sequence of characters (including no characters) and a question mark (?) matches any single character. This notation is comparable to Unix shell file name patterns. For example, \dt int* displays tables whose names begin with int. But within double quotation marks, the asterisk (*) and the question mark (?) lose these special meanings and are just matched literally.
A pattern that contains a dot (.) is interpreted as a schema name pattern followed by an object name pattern. For example, \dt foo*.*bar* displays all tables (whose names include bar) in schemas starting with foo. If no dot appears, then the pattern matches only visible objects in the current schema search path. Again, a dot within double quotation marks loses its special meaning and is matched literally.
Advanced users can use regular-expression notations, such as character classes. For example [0-9] can be used to match any digit. All regular expression special characters, except the following, work as specified in POSIX regular expressions:
- A dot (.) is used as a separator.
- An asterisk (*) is translated into an asterisk prefixed with a dot (.*), which is a regular-expression marking.
- A question mark (?) is translated into a dot (.).
- A dollar sign ($) is matched literally.
You can, as required, write ?, (R+|), (R|), and R to the following PATTERN characters: ., R*, and R?. The dollar sign ($) does not need to work as a regular-expression character since the pattern must match the whole name, which is different from the usual interpretation of regular expressions. In other words, the dollar sign ($) is automatically appended to your pattern. If you do not expect a pattern to be anchored, write an asterisk (*) at its beginning or end. All regular-expression special characters within double quotation marks lose their special meanings and are matched literally. Regular-expression special characters in operator name patterns (such as the \do parameter) are also matched literally.
FAQs
Low Connection Performance
log_hostname is enabled, but DNS is incorrect.
Connect to the database, and run show log_hostname to check whether log_hostname is enabled in the database.
If it is enabled, the database kernel will use DNS to check the name of the host where the client is deployed. If the primary database node is configured with an incorrect or unreachable DNS server, the database connection will take a long time to set up. For details about this parameter, see the description of log_hostname in section Log Content.
The database kernel slowly runs the initialization statement.
Problems are difficult to locate in this scenario. Try using the strace Linux trace command.
strace gsql -U MyUserName -W MyPassWord -d postgres -h 127.0.0.1 -p 23508 -r -c '\q'
The database connection process will be printed on the screen. If the following statement takes a long time to run:
sendto(3, "Q\0\0\0\25SELECT VERSION()\0", 22, MSG_NOSIGNAL, NULL, 0) = 22 poll([{fd=3, events=POLLIN|POLLERR}], 1, -1) = 1 ([{fd=3, revents=POLLIN}])
It indicates that the SELECT VERSION() statement was run slowly.
After the database is connected, you can run the explain performance select version() statement to find the reason why the initialization statement was run slowly. For more information, see SQL Execution Plan.
An uncommon scenario is that the disk of the machine where the primary database node resides is full or faulty, affecting queries and leading to user authentication failures. As a result, the connection process is suspended. To solve this problem, simply clear the data disk space of the primary database node.
TCP connection is set up slowly.
Adapt the steps of troubleshooting slow initialization statement execution. Use strace. If the following statement is run slowly:
connect(3, {sa_family=AF_FILE, path="/home/test/tmp/gaussdb_llt1/.s.PGSQL.61052"}, 110) = 0
Or,
connect(3, {sa_family=AF_INET, sin_port=htons(61052), sin_addr=inet_addr("127.0.0.1")}, 16) = -1 EINPROGRESS (Operation now in progress)
It indicates that the physical connection between the client and the database is set up slowly. In this case, check whether the network is unstable or has high throughput.
Problems in Setting Up Connections
gsql: could not connect to server: No route to host
This problem occurs generally because an unreachable IP address or port number was specified. Check whether the values of -h and -p parameters are correct.
gsql: FATAL: Invalid username/password,login denied.
This problem occurs generally because an incorrect username or password was entered. Contact the database administrator to check whether the username and password are correct.
gsql: FATAL: Forbid remote connection with trust method!
For security purposes, remote login in trust mode is forbidden. In this case, you need to modify the connection authentication information in the pg_hba.conf file. For details, see Configuration File Reference.
NOTE: Do not modify the configurations of the openGauss host in the pg_hba. conf file. Otherwise, the database may become faulty. It is recommended that service applications be deployed outside the openGauss.
If -h 127.0.0.1 is specified, the database connection is successful. If -h 127.0.0.1 is removed, the connection fails.
Run the show unix_socket_directory SQL statement to check whether the Unix socket directory used by the primary database node is the same as that specified by $PGHOST in the shell directory.
If they are different, set $PGHOST to the directory specified by unix_socket_directory.
For more information about unix_socket_directory, see Connection Settings.
The “libpq.so” loaded mismatch the version of gsql, please check it.
This problem occurs because the version of libpq.so used in the environment does not match that of gsql. Run the ldd gsql command to check the version of the loaded libpq.so, and then load correct libpq.so by modifying the environment variable LD_LIBRARY_PATH.
gsql: symbol lookup error: xxx/gsql: undefined symbol: libpqVersionString
This problem occurs because the version of libpq.so used in the environment does not match that of gsql (or the PostgreSQL libpq.so exists in the environment). Run the ldd gsql command to check the version of the loaded libpq.so, and then load correct libpq.so by modifying the environment variable LD_LIBRARY_PATH.
gsql: connect to server failed: Connection timed out
Is the server running on host “xx.xxx.xxx.xxx” and accepting TCP/IP connections on port xxxx?
This problem is caused by network connection faults. Check the network connection between the client and the database server. If you cannot ping from the client to the database server, the network connection is abnormal. Contact network management personnel for troubleshooting.
ping -c 4 10.10.10.1 PING 10.10.10.1 (10.10.10.1) 56(84) bytes of data. From 10.10.10.1: icmp_seq=2 Destination Host Unreachable From 10.10.10.1 icmp_seq=2 Destination Host Unreachable From 10.10.10.1 icmp_seq=3 Destination Host Unreachable From 10.10.10.1 icmp_seq=4 Destination Host Unreachable --- 10.10.10.1 ping statistics --- 4 packets transmitted, 0 received, +4 errors, 100% packet loss, time 2999ms
gsql: FATAL: permission denied for database “postgres”
DETAIL: User does not have CONNECT privilege.
This problem occurs because the user does not have the permission to access the database. To solve this problem, perform the following steps:
Connect to the database as the system administrator dbadmin.
gsql -d postgres -U dbadmin -p 15400
Grant the user with the permission to access the database.
GRANT CONNECT ON DATABASE postgres TO user1;
NOTE: Actually, some common misoperations may also cause a database connection failure, for example, entering an incorrect database name, username, or password. Misoperations are accompanied with an error information on the client tool.
gsql -d postgres -p 15400 gsql: FATAL: database "postgres" does not exist gsql -d postgres -U user1 -W gauss@789 -p 15400 gsql: FATAL: Invalid username/password,login denied.
gsql: FATAL: sorry, too many clients already, active/non-active: 2/10/3.
This problem occurs because the number of system connections exceeds the upper limit. Contact the database administrator to release unnecessary sessions.
For details about how to view the number of user session connections, see Table 23.
You can view the session status in the PG_STAT_ACTIVITY view. To release unnecessary sessions, use the pg_terminate_backend function.
select datid,pid,state from pg_stat_activity;
datid | pid | state -------+-----------------+-------- 13205 | 139834762094352 | active 13205 | 139834759993104 | idle (2 rows)
The value of pid is the thread ID of the session. Terminate the session using its thread ID.
SELECT PG_TERMINATE_BACKEND(139834759993104);
If a command output similar to the following is displayed, the session is successfully terminated.
PG_TERMINATE_BACKEND ---------------------- t (1 row)
Table 23 Viewing the number of session connections
gsql: wait xxx.xxx.xxx.xxx:xxxx timeout expired
When gsql initiates a connection request to the database, a 5-minute timeout period is used. If the database cannot correctly authenticate the client request and client identity within this period, gsql will exit the connection process for the current session, and will report the above error.
Generally, this problem is caused by the incorrect host and port (that is, the xxx part in the error information) specified by the -h and -p parameters. As a result, the communication fails. Occasionally, this problem is caused by network faults. To resolve this problem, check whether the host name and port number of the database are correct.
gsql: could not receive data from server: Connection reset by peer.
Check whether primary database node logs contain information similar to “FATAL: cipher file “/data/dbnode/server.key.cipher” has group or world access”. This error is usually caused by tampering with the permissions for data directories or some key files by mistake. For details about how to correct the permissions, see related permissions for files on other normal instances.
gsql: FATAL: GSS authentication method is not allowed because XXXX user password is not disabled.
In pg_hba.conf of the target primary database node, the authentication mode is set to gss for authenticating the IP address of the current client. However, this authentication algorithm cannot authenticate clients. Change the authentication algorithm to sha256 and try again. For details, see Configuration File Reference.
NOTE:
- Do not modify the configurations of the openGauss host in the pg_hba. conf file. Otherwise, the database may become faulty.
- It is recommended that service applications be deployed outside the openGauss.
Other Faults
There is a core dump or abnormal exit due to the bus error.
Generally, this problem is caused by changes in loading the shared dynamic library (.so file in Linux) during process running. Alternatively, if the process binary file changes, the execution code for the OS to load machines or the entry for loading a dependent library will change accordingly. In this case, the OS kills the process for protection purposes, generating a core dump file.
To resolve this problem, try again. In addition, do not run service programs in openGauss during O&M operations, such as an upgrade, preventing such a problem caused by file replacement during the upgrade.
NOTE: A possible stack of the core dump file contains dl_main and its function calling. The file is used by the OS to initialize a process and load the shared dynamic library. If the process has been initialized but the shared dynamic library has not been loaded, the process cannot be considered completely started.