zitadel/cmd/setup/40/postgres/02_func.sql
Tim Möhlmann 92265dca21
fix(setup): use template for in_tx_order type (#9346)
# Which Problems Are Solved

Systems running with PostgreSQL before Zitadel v2.39 are likely to have
a wrong type for the `in_tx_order` column in the `eventstore.event2`
table. The migration at the time used the `event_sequence` as default
value without typecast, which results in a `bigint` type for that
column. However, when creating the table from scratch, we explicitly
specify the type to be `integer`.

Starting from Zitadel v2.67 we use a Pl/PgSQL function to push events.
The function requires the types from `eventstore.events2` to the same as
the `select` destinations used in the function. In the function
`in_tx_order` is also expected to by of `integer` type.

CochroachDB systems are not affected because `bigint` is an alias to the
`int` type. In other words, CockroachDB uses `int8` when specifying type
`int`. Therefore the types already match.

# How the Problems Are Solved

Retrieve the actual column type currently in use. A template is used to
assign the type to the `ordinality` column returned as `in_tx_order`.

# Additional Changes

- Detailed logging on migration failure

# Additional Context

- Closes #9180

---------

Co-authored-by: Silvan <27845747+adlerhurst@users.noreply.github.com>
(cherry picked from commit bcc6a689fab919f480694be254905d18d48ce565)
2025-02-13 17:15:36 +01:00

93 lines
2.4 KiB
PL/PgSQL

CREATE OR REPLACE FUNCTION eventstore.latest_aggregate_state(
instance_id TEXT
, aggregate_type TEXT
, aggregate_id TEXT
, sequence OUT BIGINT
, owner OUT TEXT
)
LANGUAGE 'plpgsql'
STABLE PARALLEL SAFE
AS $$
BEGIN
SELECT
COALESCE(e.sequence, 0) AS sequence
, e.owner
INTO
sequence
, owner
FROM
eventstore.events2 e
WHERE
e.instance_id = $1
AND e.aggregate_type = $2
AND e.aggregate_id = $3
ORDER BY
e.sequence DESC
LIMIT 1;
RETURN;
END;
$$;
CREATE OR REPLACE FUNCTION eventstore.commands_to_events(commands eventstore.command[])
RETURNS SETOF eventstore.events2
LANGUAGE 'plpgsql'
STABLE PARALLEL SAFE
ROWS 10
AS $$
DECLARE
"aggregate" RECORD;
current_sequence BIGINT;
current_owner TEXT;
BEGIN
FOR "aggregate" IN
SELECT DISTINCT
instance_id
, aggregate_type
, aggregate_id
FROM UNNEST(commands)
LOOP
SELECT
*
INTO
current_sequence
, current_owner
FROM eventstore.latest_aggregate_state(
"aggregate".instance_id
, "aggregate".aggregate_type
, "aggregate".aggregate_id
);
RETURN QUERY
SELECT
c.instance_id
, c.aggregate_type
, c.aggregate_id
, c.command_type -- AS event_type
, COALESCE(current_sequence, 0) + ROW_NUMBER() OVER () -- AS sequence
, c.revision
, NOW() -- AS created_at
, c.payload
, c.creator
, COALESCE(current_owner, c.owner) -- AS owner
, EXTRACT(EPOCH FROM NOW()) -- AS position
, c.ordinality::{{ .InTxOrderType }} -- AS in_tx_order
FROM
UNNEST(commands) WITH ORDINALITY AS c
WHERE
c.instance_id = aggregate.instance_id
AND c.aggregate_type = aggregate.aggregate_type
AND c.aggregate_id = aggregate.aggregate_id;
END LOOP;
RETURN;
END;
$$;
CREATE OR REPLACE FUNCTION eventstore.push(commands eventstore.command[]) RETURNS SETOF eventstore.events2 VOLATILE AS $$
INSERT INTO eventstore.events2
SELECT * FROM eventstore.commands_to_events(commands)
ORDER BY in_tx_order
RETURNING *
$$ LANGUAGE SQL;