Security Functions¶
gs_password_deadline()¶
Description: Displays the time before the password of the current account expires. After the password expires, the system prompts the user to change the password. This parameter is related to the GUC parameter password_effect_time.
Return type: interval
Examples:
SELECT gs_password_deadline();
gs_password_deadline
-------------------------
83 days 17:44:32.196094
(1 row)
gs_password_expiration()¶
Description: Displays the time before the password of the current account expires. After the password expires, the user cannot log in to the database. This parameter is related to the DDL statement PASSWORD EXPIRATION period for creating a user. The return value of the function is greater than or equal to -1. If PASSWORD EXPIRATION period is not specified during user creation, the default value is -1, indicating that there is no expiration limit.
Return type: interval
Examples:
SELECT gs_password_expiration();
gs_password_expiration
-------------------------
29 days 23:59:49.731482
(1 row)
login_audit_messages(flag boolean)¶
Description: Queries login information about a login user.
Return type: tuple
Examples:
Checks the date, time, and IP address successfully authenticated during the last login.
SELECT * FROM login_audit_messages(true); username | database | logintime | type | result | client_conninfo | session_id ------------+----------+------------------------+---------------+--------+--------------------+----------------------------------------- dbadmin | gaussdb | 2017-06-02 15:28:34+08 | login_success | ok | gsql@[local] | 1663745305.140192538154752.coordinator1 (1 row)
Checks the date, time, and IP address that failed to be authenticated during the last login.
SELECT * FROM login_audit_messages(false) ORDER BY logintime desc limit 1; username | database | logintime | type | result | client_conninfo | session_id ------------+----------+------------------------+--------------+--------+-------------------------+------------ (0 rows)
Checks the number of failed attempts, date, and time since the previous successful authentication.
SELECT * FROM login_audit_messages(false); username | database | logintime | type | result | client_conninfo | session_id ------------+----------+------------------------+--------------+--------+-------------------------+------------ (0 rows)
login_audit_messages_pid(flag boolean)¶
Description: Queries login information about a login user. Different from login_audit_messages, this function queries login information based on backendid. Information about subsequent logins of the same user does not alter the query result of previous logins and cannot be found using this function.
Return type: tuple
Examples:
Checks the date, time, and IP address successfully authenticated during the last login.
SELECT * FROM login_audit_messages_pid(true); username | database | logintime | type | result | client_conninfo | backendid | session_id ------------+----------+------------------------+---------------+--------+--------------------+----------------------------------------- dbadmin | postgres | 2017-06-02 15:28:34+08 | login_success | ok | gsql@[local] | 140311900702464 | 1663745305.140192538154752.coordinator1 (1 row)
Checks the date, time, and IP address that failed to be authenticated during the last login.
SELECT * FROM login_audit_messages_pid(false) ORDER BY logintime desc limit 1; username | database | logintime | type | result | client_conninfo | backendid | session_id ------------+----------+------------------------+--------------+--------+-------------------------+------------ (0 rows)
Checks the number of failed attempts, date, and time since the previous successful authentication.
SELECT * FROM login_audit_messages_pid(false); username | database | logintime | type | result | client_conninfo | backendid | session_id ------------+----------+------------------------+--------------+--------+-------------------------+------------ (0 rows)
pg_query_audit()¶
Description: Displays audit logs of the CN.
Return type: record
The following table describes return columns.
Parameter | Type | Description |
---|---|---|
begintime | timestamp with time zone | Operation start time |
endtime | timestamp with time zone | Operation end time |
operation_type | text | Operation type. For details, see Table 2. |
audit_type | text | Audit type. For details, see Table 3. |
result | text | Operation result |
username | text | Name of the user who performs the operation |
database | text | Database name |
client_conninfo | text | Client connection information, that is, gsql, JDBC, or ODBC. |
object_name | text | Object name |
object_details | text | Columns involved in the statement and their types. |
command_text | text | Command used to perform the operation |
detail_info | text | Operation details |
transaction_xid | text | Transaction ID |
query_id | text | Query ID |
node_name | text | Node name |
session_id | text | ID of a session. |
local_port | text | Local port |
remote_port | text | Remote port |
result_rows | text | Number of records returned after the statement is executed. |
error_code | text | Error code returned when a statement execution error occurs. |
Operation type | Description |
---|---|
audit_switch | Indicates that the operations of enabling and disabling the audit log function are audited. |
login_logout | Indicates that user login and log-out operations are audited. |
system | Indicates that the system startup, shutdown, and instance switchover operations are audited. |
sql_parse | Indicates that SQL statement parsing operations are audited. |
user_lock | Indicates that user locking and unlocking operations are audited. |
grant_revoke | Indicates that user permission granting and revoking operations are audited. |
violation | Indicates that user's access violation operations are audited. |
ddl | Indicates that DDL operations are audited. DDL operations are controlled at a fine granularity based on operation objects. Therefore, audit_system_object is used to control the objects whose DDL operations are to be audited. (The audit function takes effect as long as audit_system_object is configured, no matter whether ddl is set.) |
dml | Indicates that the DML operations are audited. |
select | Indicates that the SELECT operations are audited. |
internal_event | Indicates that internal incident operations are audited. |
user_func | Indicates that operations related to user-defined functions, stored procedures, and anonymous blocks are audited. Note If a user-defined function or stored procedure contains a FETCH statement, the common_text field records the corresponding CURSOR content when the fetch statement is audited. |
special_func | Indicates that special function invoking operations are audited. Special functions include pg_terminate_backend and pg_cancel_backend. |
copy | Indicates that the COPY operations are audited. |
set | Indicates that the SET operations are audited. |
transaction | Indicates that transaction operations are audited. |
vacuum | Indicates that the VACUUM operations are audited. |
analyze | Indicates that the ANALYZE operations are audited. |
cursor | Indicates that cursor operations are audited. |
anonymous_block | Indicates that the anonymous block operations are audited. |
explain | Indicates that the EXPLAIN operations are audited. |
show | Indicates that the SHOW operations are audited. |
lock_table | Indicates that table lock operations are audited. |
comment | Indicates that the COMMENT operations are audited. |
preparestmt | Indicates that the PREPARE, EXECUTE, and DEALLOCATE operations are audited. |
cluster | Indicates that the CLUSTER operations are audited. |
constraints | Indicates that the CONSTRAINTS operations are audited. |
checkpoint | Indicates that the CHECKPOINT operations are audited. |
barrier | Indicates that the BARRIER operations are audited. |
cleanconn | Indicates that the CLEAN CONNECTION operations are audited. |
seclabel | Indicates that security label operations are audited. |
notify | Indicates that the notification operations are audited. |
load | Indicates that the loading operations are audited. |
discard | Indicates that all global temporary tables of the current session are audited. |
Parameter | Description |
---|---|
audit_open/audit_close | Indicates that the audit type is operations enabling or disabling audit logs. |
user_login/user_logout | Indicates that the audit type is operations and users with successful login/logout. |
system_start/system_stop/system_recover/system_switch | Indicates that the audit type is system startup, shutdown, and instance switchover. |
sql_wait/sql_parse | Indicates that the audit type is SQL statement parsing. |
lock_user/unlock_user | Indicates that the audit type is successful user locking and unlocking. |
grant_role/revoke__role | Indicates that the audit type is user permission granting and revoking. |
user_violation | Indicates that the audit type is unauthorized user access operations. |
ddl_database_object | Indicates that successful DDL operations are audited. DDL operations are controlled at a fine granularity based on operation objects. So, audit_system_object is used to control the objects whose DDL operations are to be audited. (The audit function takes effect as long as audit_system_object is configured, no matter whether ddl is set.) For example, ddl_sequence indicates that the audit type is sequence-related operations. |
dml_action_insert/dml_action_delete/dml_action_update/dml_action_merge/dml_action_select | Indicates that the audit type is DML operations such as INSERT, DELETE, UPDATE, and MERGE. |
internal_event | Indicates that the audit type is internal events. |
user_func | Indicates that the audit type is user-defined functions, stored procedures, or anonymous block operations. Note If a user-defined function or stored procedure contains a FETCH statement, the common_text field records the corresponding CURSOR content when the fetch statement is audited. |
special_func | Indicates that the audit type is special function invocation. Special functions include pg_terminate_backend and pg_cancel_backend. |
copy_to/copy_from | Indicates that the audit type is COPY operations. |
set_parameter | Indicates that the audit type is SET operations. |
trans_begin/trans_commit/trans_prepare/trans_rollback_to/trans_release/trans_savepoint/trans_commit_prepare/trans_rollback_prepare/trans_rollback | Indicates that the audit type is transaction-related operations. |
vacuum/vacuum_full/vacuum_merge | Indicates that the audit type is VACUUM operations. |
analyze/analyze_verify | Indicates that the audit type is ANALYZE operations. |
cursor_declare/cursor_move/cursor_fetch/cursor_close | Indicates that the audit type is cursor-related operations. |
codeblock_execute | Indicates that the audit type is anonymous blocks. |
explain | Indicates that the audit type is EXPLAIN operations. |
show | Indicates that the audit type is SHOW operations. |
lock_table | Indicates that the audit type is table locking operations. |
comment | Indicates that the audit type is COMMENT operations. |
prepare/execute/deallocate | Indicates that the audit type is PREPARE, EXECUTE, or DEALLOCATE operations. |
cluster | Indicates that the audit type is CLUSTER operations. |
constraints | Indicates that the audit type is CONSTRAINTS operations. |
checkpoint | Indicates that the audit type is CHECKPOINT operations. |
barrier | Indicates that the audit type is BARRIER operations. |
cleanconn | Indicates that the audit type is CLEAN CONNECTION operations. |
seclabel | Indicates that the audit type is security label operations. |
notify | Indicates that the audit type is notification operations. |
load | Indicates that the audit type is loading operations. |
discard | Indicates that the audit type is DISCARD operations. |
pgxc_query_audit()¶
Description: Displays audit logs of all CNs.
Return type: record
The return fields of this function are the same as those of the pg_query_audit function.
pg_query_audit_details()¶
Description: Views audit logs and parses the object_name and object_details columns in audit logs from JSON format. This function is supported only by clusters of version 8.2.1.100 or later.
Return type: record
The following table describes return columns.
Parameter | Type | Description |
---|---|---|
begintime | timestamp with time zone | Operation start time |
endtime | timestamp with time zone | Operation end time |
operation_type | text | Operation type. For details, see Table 2. |
audit_type | text | Audit type. For details, see Table 3. |
result | text | Operation result |
username | text | Name of the user who performs the operation |
database | text | Database name |
client_conninfo | text | Client connection information, that is, gsql, JDBC, or ODBC. |
transaction_xid | text | Transaction ID |
query_id | text | Query ID |
node_name | text | Node name |
session_id | text | ID of a session. |
local_port | text | Local port |
remote_port | text | Remote port |
object_name | text | Table name, function name, and view name. |
column_name | text | Column name |
type_of_use | text | Usage type of an object. The options are as follows: 1: reference only (This flag does not exist in actual use.) 2: accessed during execution (columns in the statement and columns accessed during parsing) 4: found in condition statements (excluding condition expressions and functions) 8: found in inner join 16: found in outer join 32: found in aggregation nodes (including distinct, group by, and aggregate functions) 64: found in full join The values in this column are displayed in overlay mode. |
use_type | text | Type parsed by type_of_use: 1: Reference only 2: Access 4: Conditional 8: Inner join 16: Outer join 32: Sum 64: Full join |
command_text | text | Command used to perform the operation |
Examples:
Query the column names of all objects and object types used in the statement.
SET audit_object_details = on; SELECT object_name,object_details,result_rows,error_code,command_text FROM pg_query_audit('2023-05-12-03 8:00:00','2023-05-12 22:55:00') where command_text like '%student%';
The query result is as follows:
object_name | object_details | result_rows | error_code | command_text ------------------------------------------------------------------+------------------------------------------------------------------------------------------+-------------+------------+------------------------------------------------------------------------------------------------------------------------------------------------------- student | | 0 | | CREATE TABLE student(stuNo int, stuName TEXT); studentscore | | 0 | | CREATE TABLE studentscore(stuNo int, stuscore int); ["public.student_view01","public.studentscore","public.student"] | | 0 | | CREATE OR REPLACE VIEW student_view01 AS SELECT * FROM student t1 where t1.stuNo in (select stuNo from studentscore t2 where t1.stuNo = t2.stuNo); ["public.student_view01","public.student","public.studentscore"] | {"public.student":[{"stuno":"6"},{"stuname":"2"}],"public.studentscore":[{"stuno":"6"}]} | 0 | | SELECT * FROM student_view01
The object_details column in the query result displays the columns involved in the execution and their usage types. The columns are recorded in JSON format.
You can use the pg_query_audit_details function to parse the object_name and object_details columns.
SELECT database,object_name,column_name,type_of_use,use_type FROM pg_query_audit_details('2021-02-03 8:00:00','2024-02-03 22:55:00','current') where command_text like '%student%';
The query result is as follows:
database | object_name | column_name | type_of_use | use_type ----------+-----------------------+-------------+-------------+-------------------- gaussdb | student | | 2 | Access gaussdb | | | 2 | Access gaussdb | studentscore | | 2 | Access gaussdb | | | 2 | Access gaussdb | public.student_view01 | | 2 | Access gaussdb | public.studentscore | | 2 | Access gaussdb | public.student | | 2 | Access gaussdb | | | 2 | Access gaussdb | public.student | stuno | 6 | Access,Conditional gaussdb | public.student | stuname | 2 | Access gaussdb | public.studentscore | stuno | 6 | Access,Conditional gaussdb | public.student_view01 | | 2 | Access gaussdb | public.student | | 2 | Access gaussdb | public.studentscore | | 2 | Access gaussdb | | | 2 | Access (15 rows)
pg_delete_audit()¶
Note
For database security concerns, this function is unavailable. If you call it, the following message is displayed: "ERROR: For security purposes, it is not allowed to manually delete audit logs."
create_audit_csv_foregion_table()¶
Description: Creates a partitioned foreign table for reading audit logs. You can invoke this function to generate the audit log foreign table pgxc_audit_logs. By reading pgxc_audit_logs, you can read audit logs stored on OBS. This function is supported only by clusters of 8.2.1.300 or later.
Input parameter:
obs_server: OBS server name. The value is of the text type.
file_path: OBS file path. The value is of the text type.
Return type: record
Examples:
-- Create an OBS server.
CREATE SERVER obs_server FOREIGN DATA WRAPPER DFS_FDW OPTIONS (
address 'obs.example.com:xxx',
encrypt 'true',
access_key 'xxxxxxxxx',
secret_access_key 'xxxxxxxxxxxxxx',
type 'obs' );
-- Invoke this function to generate a foreign table for audit logs.
SELECT * FROM pg_catalog.create_audit_csv_foregion_table('obs_server','/obs-audit/test/');
create_audit_csv_foregion_table
---------------------------------
t
(1 row)
-- Read audit logs stored on OBS.
SELECT * FROM pgxc_audit_logs where year=2023 and month=7 and date=24;
year | month | date | begintime | endtime | operation_type | audit_type | result | username | database | client_conninfo | object_name | object_details |command_text| detail_info | transaction_xid | query_id | node_name | session_id | local_port | remote_port | result_rows | error_code
------+-------+------+----------------------------+----------------------------+----------------+-------------------+--------+----------+----------+-----------------+--------------------------------+----------------+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------+-------------+-----------------+--------------------+-----------+------------------------------------+------------+-------------+-------------+------------
2023 | 7 | 24 | 2023-07-24 09:56:40.727+08 | 2023-07-24 09:56:42.215+08 | dml | dml_action_select | ok | dbadmin | gaussdb | gsql@[local] | public.pgxc_audit_logs | | select * f
rom pgxc_audit_logs where year=2023 and date=24 and month=7;