lemmy/crates/db_schema/replaceable_schema/utils.sql

147 lines
5.5 KiB
MySQL
Raw Normal View History

Move SQL triggers from migrations into reusable sql file (#4333) * stuff * stuff including batch_upsert function * stuff * do things * stuff * different timestamps * stuff * Revert changes to comment.rs * Update comment.rs * Update comment.rs * Update post_view.rs * Update utils.rs * Update up.sql * Update up.sql * Update down.sql * Update up.sql * Update main.rs * use anyhow macro * Create down.sql * Create up.sql * Create replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update utils.rs * Update .woodpecker.yml * Update sql_format_check.sh * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Create dump_schema.sh * Update start_dev_db.sh * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * Update replaceable_schema.sql * stuff * Update replaceable_schema.sql * Update .pg_format * fmt * stuff * stuff (#21) * Update replaceable_schema.sql * Update up.sql * Update replaceable_schema.sql * fmt * update cargo.lock * stuff * Update replaceable_schema.sql * Remove truncate trigger because truncate is already restricted by foreign keys * Update replaceable_schema.sql * fix some things * Update replaceable_schema.sql * Update replaceable_schema.sql * Update .woodpecker.yml * stuff * fix TG_OP * Psql env vars * try to fix combine_transition_tables parse error * Revert "try to fix combine_transition_tables parse error" This reverts commit 75d00a46266fbb49b7fab1b149c79fa1c31ee84a. * refactor combine_transition_tables * try to fix create_triggers * fix some things * try to fix combined_transition_tables * fix sql errors * update comment count in post trigger * fmt * Revert "fmt" This reverts commit a5bcd0834bb91a63b66bf63a848caa078f193940. * Revert "update comment count in post trigger" This reverts commit 0066a4b42b3472c088eed945605a2cf0bfcc1362. * fix everything * Update replaceable_schema.sql * actually fix everything * refactor create_triggers * fix * add semicolons * add is_counted function and fix incorrect bool operator in update_comment_count_from_post * refactor comment trigger * refactor post trigger * fix * Delete crates/db_schema/src/utils/series.rs * subscribers_local * edit migrations * move migrations * remove utils::series module declaration * fix everything * stuff * Move sql to schema_setup dir * utils.sql * delete .pg_format * Update .woodpecker.yml * Update sql_format_check.sh * Update .woodpecker.yml * Merge remote-tracking branch 'upstream/main' into bliss * fmt * Create main.rs * Update lib.rs * Update main.rs * Update .woodpecker.yml * Update main.rs * Update Cargo.toml * Update .woodpecker.yml * Update .woodpecker.yml * Update triggers.sql * YAY * Update mod.rs * Update Cargo.toml * a * Update Cargo.toml * Update Cargo.toml * Delete crates/db_schema/src/main.rs * Update Cargo.toml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update utils.sql * Update utils.sql * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update down.sql * Update up.sql * Update triggers.sql * Update .woodpecker.yml * Update .woodpecker.yml * Update triggers.sql * Update down.sql * Update .woodpecker.yml * Update Cargo.toml * Update .woodpecker.yml * Update Cargo.toml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update .woodpecker.yml * Update mod.rs * Update Cargo.toml * Update mod.rs * make dump_schema.sh executable * fix dump_schema.sh * defer * diff dumps * fmt * Update utils.sql * Update .woodpecker.yml * use correct version for pg_dump * Update .woodpecker.yml * Update .woodpecker.yml * change migration date * atomic site_aggregates insert * temporarily repeat tests in CI * drop r schema in CI migration check * show ReceivedActivity::create error * move check_diesel_migration CI step * Update .woodpecker.yml * Update scheduled_tasks.rs * Update scheduled_tasks.rs * update cargo.lock * move sql files * move rank functions * filter post_aggregates update * fmt * cargo fmt * replace post_id with id * update cargo.lock * avoid locking rows that need no change in up.sql * only run replaceable_schema if migrations were run * debug ci test failure * make replaceable_schema work in CI * Update .woodpecker.yml * remove println * Use migration revert and git checkout * Update schema_setup.rs * Fix * Update schema_setup.rs * Update schema_setup.rs * Update .woodpecker.yml --------- Co-authored-by: Nutomic <me@nutomic.com> Co-authored-by: Dessalines <dessalines@users.noreply.github.com>
2024-04-17 18:58:44 -06:00
-- Each calculation used in triggers should be a single SQL language
-- expression so it can be inlined in migrations.
CREATE FUNCTION r.controversy_rank (upvotes numeric, downvotes numeric)
RETURNS float
LANGUAGE sql
IMMUTABLE PARALLEL SAFE RETURN CASE WHEN downvotes <= 0
OR upvotes <= 0 THEN
0
ELSE
(
upvotes + downvotes) * CASE WHEN upvotes > downvotes THEN
downvotes::float / upvotes::float
ELSE
upvotes::float / downvotes::float
END
END;
CREATE FUNCTION r.hot_rank (score numeric, published timestamp with time zone)
RETURNS double precision
LANGUAGE sql
IMMUTABLE PARALLEL SAFE RETURN
-- after a week, it will default to 0.
CASE WHEN (
now() - published) > '0 days'
AND (
now() - published) < '7 days' THEN
-- Use greatest(2,score), so that the hot_rank will be positive and not ignored.
log (
greatest (2, score + 2)) / power (((EXTRACT(EPOCH FROM (now() - published)) / 3600) + 2), 1.8)
ELSE
-- if the post is from the future, set hot score to 0. otherwise you can game the post to
-- always be on top even with only 1 vote by setting it to the future
0.0
END;
CREATE FUNCTION r.scaled_rank (score numeric, published timestamp with time zone, users_active_month numeric)
RETURNS double precision
LANGUAGE sql
IMMUTABLE PARALLEL SAFE
-- Add 2 to avoid divide by zero errors
-- Default for score = 1, active users = 1, and now, is (0.1728 / log(2 + 1)) = 0.3621
-- There may need to be a scale factor multiplied to users_active_month, to make
-- the log curve less pronounced. This can be tuned in the future.
RETURN (
r.hot_rank (score, published) / log(2 + users_active_month)
);
-- For tables with `deleted` and `removed` columns, this function determines which rows to include in a count.
CREATE FUNCTION r.is_counted (item record)
RETURNS bool
LANGUAGE plpgsql
IMMUTABLE PARALLEL SAFE
AS $$
BEGIN
RETURN COALESCE(NOT (item.deleted
OR item.removed), FALSE);
END;
$$;
-- This function creates statement-level triggers for all operation types. It's designed this way
-- because of these limitations:
-- * A trigger that uses transition tables can only handle 1 operation type.
-- * Transition tables must be relevant for the operation type (for example, `NEW TABLE` is
-- not allowed for a `DELETE` trigger)
-- * Transition tables are only provided to the trigger function, not to functions that it calls.
--
-- This function can only be called once per table. The trigger function body given as the 2nd argument
-- and can contain these names, which are replaced with a `SELECT` statement in parenthesis if needed:
-- * `select_old_rows`
-- * `select_new_rows`
-- * `select_old_and_new_rows` with 2 columns:
-- 1. `count_diff`: `-1` for old rows and `1` for new rows, which can be used with `sum` to get the number
-- to add to a count
-- 2. (same name as the trigger's table): the old or new row as a composite value
CREATE PROCEDURE r.create_triggers (table_name text, function_body text)
LANGUAGE plpgsql
AS $a$
DECLARE
defs text := $$
-- Delete
CREATE FUNCTION r.thing_delete_statement ()
RETURNS TRIGGER
LANGUAGE plpgsql
AS function_body_delete;
CREATE TRIGGER delete_statement
AFTER DELETE ON thing REFERENCING OLD TABLE AS select_old_rows
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_delete_statement ( );
-- Insert
CREATE FUNCTION r.thing_insert_statement ( )
RETURNS TRIGGER
LANGUAGE plpgsql
AS function_body_insert;
CREATE TRIGGER insert_statement
AFTER INSERT ON thing REFERENCING NEW TABLE AS select_new_rows
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_insert_statement ( );
-- Update
CREATE FUNCTION r.thing_update_statement ( )
RETURNS TRIGGER
LANGUAGE plpgsql
AS function_body_update;
CREATE TRIGGER update_statement
AFTER UPDATE ON thing REFERENCING OLD TABLE AS select_old_rows NEW TABLE AS select_new_rows
FOR EACH STATEMENT
EXECUTE FUNCTION r.thing_update_statement ( );
$$;
select_old_and_new_rows text := $$ (
SELECT
-1 AS count_diff,
old_table::thing AS thing
FROM
select_old_rows AS old_table
UNION ALL
SELECT
1 AS count_diff,
new_table::thing AS thing
FROM
select_new_rows AS new_table) $$;
empty_select_new_rows text := $$ (
SELECT
*
FROM
-- Real transition table
select_old_rows
WHERE
FALSE) $$;
empty_select_old_rows text := $$ (
SELECT
*
FROM
-- Real transition table
select_new_rows
WHERE
FALSE) $$;
BEGIN
function_body := replace(function_body, 'select_old_and_new_rows', select_old_and_new_rows);
-- `select_old_rows` and `select_new_rows` are made available as empty tables if they don't already exist
defs := replace(defs, 'function_body_delete', quote_literal(replace(function_body, 'select_new_rows', empty_select_new_rows)));
defs := replace(defs, 'function_body_insert', quote_literal(replace(function_body, 'select_old_rows', empty_select_old_rows)));
defs := replace(defs, 'function_body_update', quote_literal(function_body));
defs := replace(defs, 'thing', table_name);
EXECUTE defs;
END;
$a$;