Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

EPAS: DB-2311 #4781

Merged
merged 24 commits into from
Sep 27, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions advocacy_docs/pg_extensions/index.mdx
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@ navigation:
- advanced_storage_pack
- ldap_sync
- pg_tuner
- spl_check
- query_advisor
- wait_states
- pg_failover_slots
Expand Down
1 change: 1 addition & 0 deletions advocacy_docs/pg_extensions/index.mdx.in
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@ navigation:
- advanced_storage_pack
- ldap_sync
- pg_tuner
- spl_check
- query_advisor
- wait_states
- pg_failover_slots
Expand Down
279 changes: 279 additions & 0 deletions advocacy_docs/pg_extensions/spl_check/configuring.mdx
Original file line number Diff line number Diff line change
@@ -0,0 +1,279 @@
---
title: Configuring EDB SPL Check
navTitle: Configuring
---

To run EDB SPL Check, use the `CREATE EXTENSION` command:

```sql
CREATE EXTENSION spl_check;
```

You can run EDB SPL Check in active mode or passive mode. In active mode, you can run checks with API functions like `spl_check_function`. In passive mode, functions are checked when executed.

## Active mode

In active mode, start checks by running API functions like `spl_check_function`. Active mode is the default behavior for EDB SPL Check. However, you can change this mode with the `spl_check.mode` setting. See [Configuring passive mode](#configuring-passive-mode) for more information.

You can also use the functions `spl_check_package`, `spl_check_objecttype`, and `spl_check_trigger` to validate your code. See [Using EDB SPL Check](using) for more information.

### Example

The validator checks the SQL statements inside SPL functions for semantic errors:

```sql
CREATE TABLE t1(a int, b int);
__OUTPUT__
CREATE TABLE
```
```sql
CREATE OR REPLACE FUNCTION public.f1()
RETURNS void
LANGUAGE edbspl
AS $function$
DECLARE r record;
BEGIN
FOR r IN SELECT * FROM t1
LOOP
RAISE NOTICE '%', r.c;
END LOOP;
END;
$function$;
__OUTPUT__
CREATE FUNCTION
```

`RAISE NOTICE '%', r.c;` indicates that there's a bug, which is that table `t1` is missing a `c` column. However, the `CREATE FUNCTION` command doesn't identify there's a bug because table `t1` is empty:

```sql
SELECT f1();
__OUTPUT__
f1
────

(1 row)
```


You can view the bug and other semantic errors by running `spl_check_function`:

```sql
SELECT * FROM spl_check_function_tb('f1()');
__OUTPUT__
─[ RECORD 1 ]───────────────────────────
functionid │ f1
lineno │ 6
statement │ RAISE
sqlstate │ 42703
message │ record "r" has no field "c"
detail │ [null]
hint │ [null]
level │ error
position │ 0
query │ [null]
```

`spl_check_function()` has three possible output formats, which are text, json, and xml:

```sql
SELECT * FROM spl_check_function('f1()', fatal_errors := false);
__OUTPUT__
spl_check_function
------------------------------------------------------------------------
error:42703:4:SQL statement:column "c" of relation "t1" does not exist
Query: update t1 set c = 30
-- ^
error:42P01:7:RAISE:missing FROM-clause entry for table "r"
Query: SELECT r.c
-- ^
error:42601:7:RAISE:too few parameters specified for RAISE
(7 rows)
```

```sql
SELECT * FROM spl_check_function('fx()', format:='xml');
__OUTPUT__
spl_check_function
────────────────────────────────────────────────────────────────
<Function oid="16400"> ↵
<Issue> ↵
<Level>error</level> ↵
<Sqlstate>42P01</Sqlstate> ↵
<Message>relation "foo111" does not exist</Message> ↵
<Stmt lineno="3">RETURN</Stmt> ↵
<Query position="23">SELECT (select a from foo111)</Query>↵
</Issue> ↵
</Function>
(1 row)
```

### Setting the level of warnings

You can use the function's parameters to set the level of warnings.

#### Required arguments

`funcoid oid`

The function name or function signature, as functions require a function specification. An oid, a name, or a signature can specify any function in PostgreSQL. Once you know the oid or a function's complete signature, you can use a `regprocedure` like `'fx()'::regprocedure` or `16799::regprocedure`. A possible alternative is to use only a name when the function's name is unique, like `'fx'`. If the name isn't unique or doesn't exist, the function raises an error.

#### Optional arguments

`relid DEFAULT 0`

The oid of the relation assigned to the trigger function. You need to check the trigger function because you're sending the table that the trigger operates on.

`fatal_errors boolean DEFAULT true`

Stop on the first error. This argument prevents massive error reports.

`other_warnings boolean DEFAULT true`

Show warnings for conditions, for example:

- Different attribute numbers are on the left and right side of assignment
- The variable overlaps the function's parameter
- Unused variables
- Unwanted casting

`extra_warnings boolean DEFAULT true`

Show warnings for conditions such as a missing `RETURN`, shadowed variables, dead code, never read (unused) function parameter, unmodified variables, and modified auto variables.

`performance_warnings boolean DEFAULT false`

Show performance-related warnings for conditions such as the declared type with type modifier, casting, and implicit casts in the `WHERE` clause (which can be the reason why an index isn't used).

`security_warnings boolean DEFAULT false`

Show security-related checks like SQL-injection vulnerability detection.

`compatibility_warnings boolean DEFAULT false`

Show compatibility-related checks like the obsolete explicit setting internal cursor names in refcursor or cursor variables.

`anyelementtype regtype DEFAULT 'int'`

Actual type to use when testing the `anyelementtype`.

`anyenumtype regtype DEFAULT '-'`

Actual type to use when testing the `anyenumtype`.

`anyrangetype regtype DEFAULT 'int4range'`

Actual type to use when testing the `anyrangetype`.

`anycompatibletype DEFAULT 'int'`

Actual type to use when testing the `anycompatibletype`.

`anycompatiblerangetype DEFAULT 'int4range'`

Actual type to use when testing the `anycompatiblerangetype`.

`without_warnings DEFAULT false`

Disable all warnings by ignoring `xxxx_warning` parameters, which is a quick override.

`all_warnings DEFAULT false`

Enable all warnings by ignoring other `xxxx_warning` parameters, which is a quick positive.

`newtable DEFAULT NULL`, `oldtable DEFAULT NULL`

The names of `NEW` or `OLD` transition tables. When transition tables are used in trigger functions, these parameters are required.

`use_incomment_options DEFAULT true`

When set to `true`, activates in-comment options.

`incomment_options_usage_warning DEFAULT false`

When set to `true`, raises a warning when in-comment options are used.


### Compatibility warnings

PostgreSQL cursor and refcursor variables are enhanced string variables that hold unique names for their respective portal. Before PostgreSQL version 16, the portal had the same name as the cursor variable. In PostgreSQL versions 16 and later, the portal has a unique name.

With this change, the refursor variable takes the value from another refcursor variable or from a cursor variable when the cursor is opened. For example:

```sql
-- obsolete pattern
DECLARE
cur CURSOR FOR SELECT 1;
rcur refcursor;
BEGIN
rcur := 'cur';
OPEN cur;
...

-- new pattern
DECLARE
cur CURSOR FOR SELECT 1;
rcur refcursor;
BEGIN
OPEN cur;
rcur := cur;
...
```

When the `compatibility_warnings` flag is active, EDB SPL Check tries to identify incorrect assigning to a refcursor variable or returning of a refcursor variable:

```sql
CREATE OR REPLACE FUNCTION public.foo()
RETURNS refcursor
AS $$
DECLARE
c cursor FOR SELECT 1;
r refcursor;
BEGIN
OPEN c;
r := 'c';
RETURN r;
END;
$$ LANGUAGE edbspl;
```
```sql
SELECT * FROM spl_check_function('foo', extra_warnings =>false, compatibility_warnings => true);
__OUTPUT__
spl_check_function
-----------------------------------------------------------------------------------
compatibility:00000:6:assignment:obsolete setting of refcursor or cursor variable
Detail: Internal name of cursor should not be specified by users.
Context: at assignment to variable "r" declared on line 3

(3 rows)
```

## Passive mode

In passive mode, EDB SPL Check can check your functions upon execution. Load the EDB SPL Check module with `postgres.conf`.

!!! Note
Passive mode is recommended only for development or preproduction use.

### Configuring passive mode

These are the EDB SPL Check settings:

```ini
spl_check.mode = [ disabled | by_function | fresh_start | every_start ]
spl_check.fatal_errors = [ yes | no ]

spl_check.show_nonperformance_warnings = false
spl_check.show_performance_warnings = false
```

By default, `spl_check.mode` is set to `by_function`, which means that checks are done only in active mode by using `spl_check_function`. `fresh_start` means cold start, so the function is called first.

To enable passive mode:

```sql
LOAD 'edb-spl'; -- 1.1 and higher doesn't need it
LOAD 'spl_check';
SET spl_check.mode = 'every_start'; -- This scans all code before it is executed

SELECT fx(10); -- run functions - function is checked before runtime starts it
```
22 changes: 22 additions & 0 deletions advocacy_docs/pg_extensions/spl_check/index.mdx
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
---
title: EDB SPL Check
directoryDefaults:
product: EDB SPL Check
---

EDB SPL Check is a code analysis tool for SPL on EDB Postgres Advanced Server. Using only the internal PostgreSQL parser, it identifies errors that can occur at runtime. In addition, it parses the SQL inside your routines and identifies errors that are usually missed when executing `CREATE PROCEDURE/FUNCTION/PACKAGE`. Similarly, it identifies errors that are usually missed when executing `CREATE PACKAGE/OBJECT TYPES/COMPOUND TRIGGER`.

You can control the levels of many warnings and hints. For instance, you can add `PRAGMA` type markers to turn certain aspects off or on, allowing you to hide messages you're already aware of or keep ones you want to be reminded of.

EDB SPL Check is supported on EDB Postgres Advanced Server versions 12 and later.

These are some of the key features of EDB SPL Check:

- Checks fields of referenced database objects and types inside embedded SQL
- Validates you're using the correct types for function parameters
- Identifies unused variables and function arguments as well as unmodified `OUT` arguments
- Partially detects dead code, that is, code after an unqualified `RETURN` command
- Detects missing `RETURN` commands in functions, which are common after exception handlers or complex logic
- Tries to identify unwanted hidden casts, which can cause performance issues like unused indexes
- Collects relations and functions used by a function
- Checks `EXECUTE` statements against SQL injection vulnerability
27 changes: 27 additions & 0 deletions advocacy_docs/pg_extensions/spl_check/using/dependency_list.mdx
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
---
title: Dependency list
---

The function `spl_show_dependency_tb` shows all the functions, operators, and relations used inside a processed function. For example:

```sql
SELECT * FROM spl_show_dependency_tb('testfunc(int,float)');
__OUTPUT__
│ type │ oid │ schema │ name │ params │
|----------|-------|--------|---------|----------------------------|
│ FUNCTION │ 36008 │ public │ myfunc1 │ (integer,double precision) │
│ FUNCTION │ 35999 │ public │ myfunc2 │ (integer,double precision) │
│ OPERATOR │ 36007 │ public │ ** │ (integer,integer) │
│ RELATION │ 36005 │ public │ myview │ │
│ RELATION │ 36002 │ public │ mytable │ │
(4 rows)
```

Optional arguments for `spl_show_dependency_tb` include:

- `relid`
- `anyelementtype`
- `enumtype`
- `anyrangetype`
- `anycompatibletype`
- `anycompatiblerangetype`
Loading
Loading