Skip to content

Conversation

griffio
Copy link
Collaborator

@griffio griffio commented Sep 15, 2025

Fixes #4812 #4795

PostgreSql Experimental 🍄😵

Very limited support for CREATE TRIGGER and CREATE FUNCTION used together - not for stand-alone CREATE FUNCTION use. DROP TRIGGER and DROP FUNCTION are also supported.

PostgreSql uses functions to execute the trigger DML unlike Sqlite where the trigger contains the executed statements.

Various fixes had to be made to override the Sqlite CREATE TRIGGER - e.g Fixtures tests that are invalid PostgreSql statements. Currently avoids the need to change sql-psi by reusing existing public core classes.

Supported Features

Call multiple statements Delete, Insert, Update e.g Insert a row into an audit table when a column is updated.

Using new and old table row references are case-sensitive because SqlDelight is when referencing table names.

CREATE TABLE accounts(
  id INT GENERATED ALWAYS AS IDENTITY,
  balance REAL
);

CREATE TABLE accounts_audit (
   account_id INT,
   balance REAL,
   changed_on TIMESTAMP NOT NULL
);

CREATE OR REPLACE TRIGGER check_update
    BEFORE UPDATE OF balance ON accounts
    FOR EACH ROW
    EXECUTE FUNCTION account_audit_update();

CREATE OR REPLACE FUNCTION account_audit_update()
RETURNS TRIGGER LANGUAGE PLPGSQL AS
$$
BEGIN
    INSERT INTO accounts_audit(account_id, balance, changed_on) VALUES (old.id, old.balance, NOW());
    RETURN new;
END;
$$;

Assign values to new records e.g Assign the current timestamp to a column each time a row is updated.
Multiple statements e.g other assignments and deletes, inserts and updates can be mixed.

CREATE TABLE organizations (
  id INTEGER NOT NULL,
  name TEXT NOT NULL,
  updated_at TIMESTAMP DEFAULT NOW() NOT NULL
);

CREATE TRIGGER organizations_set_updated_at
BEFORE UPDATE ON organizations
FOR EACH ROW
EXECUTE FUNCTION organizations_set_updated_at();

CREATE OR REPLACE FUNCTION organizations_set_updated_at()
RETURNS TRIGGER LANGUAGE PLPGSQL AS
$$
BEGIN
  new.updated_at := NOW(); 
  RETURN new;
END;
$$;

Conditionals IF ELSEIF ELSE

CREATE TABLE user_profile (
  username TEXT NOT NULL UNIQUE,
  password TEXT NOT NULL,
  password_strength TEXT
);

CREATE OR REPLACE FUNCTION user_profile_password_strength()
RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
BEGIN

  IF TG_OP = 'UPDATE' AND new.password IS NOT DISTINCT FROM old.password THEN
    RETURN new;
  END IF;

  IF length(new.password) < 6 THEN
    new.password_strength := 'weak';
  ELSIF length(new.password) < 12 THEN
    new.password_strength := 'medium';
  ELSE
    new.password_strength := 'strong';
  END IF;

  RETURN new;
END;
$$;

CREATE TRIGGER user_profile_password_strength
BEFORE INSERT OR UPDATE OF password
ON user_profile
FOR EACH ROW
EXECUTE FUNCTION user_profile_password_strength();

Add Trigger variables

CREATE OR REPLACE FUNCTION process_emp_audit()
RETURNS TRIGGER LANGUAGE PLPGSQL AS $$
BEGIN
    IF (TG_OP = 'DELETE') THEN
        INSERT INTO emp_audit SELECT 'D', NOW(), CURRENT_USER, old.empname, old.salary;
    ELSIF (TG_OP = 'UPDATE') THEN
        INSERT INTO emp_audit SELECT 'U', NOW(), CURRENT_USER, new.empname, new.salary;
    ELSIF (TG_OP = 'INSERT') THEN
        INSERT INTO emp_audit SELECT 'I', NOW(), CURRENT_USER, new.empname, new.salary;
    END IF;
    RETURN NULL; 
END;
$$;
DROP TRIGGER IF EXISTS organizations_set_updated_at ON organisations CASCADE;
DROP FUNCTION IF EXISTS organizations_set_updated_at() CASCADE;

Adds Extension statements (e.g CREATE FUNCTION) that implement SchemaContributor - to DataBaseGenerator isSchema check - so these are included in the body of the generated Schema Sample.Schema.create(driver). As the isSchema uses hard coded list of known statement types another way is needed to include a dialects schema statements e.g function, sequence.

Adds Migration Integration Test

Notes:


  • CHANGELOG.md's "Unreleased" section has been updated, if applicable.

@griffio griffio force-pushed the fix-4812-add-postgresql-create-trigger branch from 50430b3 to a3662d6 Compare September 17, 2025 13:08
Update PostgreSql.bnf

CreateTrigger and Drop Trigger overrides core sql-psi
Create Function is PostgreSql only
Schema aware for Trigger

Function todo
 remove - "if-not-exists" has invalid syntax for PostgreSql
SchemaContributor are used to create a schema
Include any SchemaContributor implementation in extension statements like CREATE FUNCTION
DROP TRIGGER ...
DROP FUNCTION ...
DROP TRIGGER ...
DROP FUNCTION ...
Add mixin for SchemaContributor support

Update DropFunctionMixin.kt
Support Multiple statements

Add top leve `plsql_assignment` rule for future use

Add `{column_expr}` to make table resolution correct
Simpler because now using `{column_expr}`
@griffio griffio force-pushed the fix-4812-add-postgresql-create-trigger branch from a3662d6 to ae79f5c Compare September 17, 2025 13:55
@griffio griffio marked this pull request as ready for review September 17, 2025 15:35
@griffio griffio mentioned this pull request Sep 18, 2025
1 task
Add IF ELSE ELSEIF conditionals to plsql
Add more fixture tests for trigger function conditionals
Add plsql_trigger_var_expression for trigger variables can be used as expression

Add  missingCURRENT_USER and SESSION_USER literals
Map literals CURRENT_USER and SESSION_USER to TEXT
These variables can be accessed for audit triggers
Use a more correct conditional matching the Postgres docs example
Copy link
Collaborator

@JakeWharton JakeWharton left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I do not feel qualified to review this. Looks mostly fine, though.

@griffio griffio merged commit 9af2197 into sqldelight:master Sep 25, 2025
18 checks passed
@griffio griffio deleted the fix-4812-add-postgresql-create-trigger branch September 25, 2025 09:20
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Development

Successfully merging this pull request may close these issues.

PostgreSql Dialect - Support for CREATE OR REPLACE TRIGGER
2 participants