feat(db): move views and functions to repeatable migrations (closes #726)

This commit is contained in:
MiniDigger | Martin 2022-11-06 20:09:47 +01:00
parent 4e156bf598
commit 393daca489
6 changed files with 382 additions and 386 deletions

View File

@ -0,0 +1,66 @@
CREATE OR REPLACE FUNCTION delete_old_project_version_download_warnings() RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
DELETE FROM project_version_download_warnings WHERE created_at < current_date - interval '30' day;
RETURN NEW;
END
$$;
CREATE OR REPLACE TRIGGER clean_old_project_version_download_warnings
AFTER INSERT
ON project_version_download_warnings
EXECUTE PROCEDURE delete_old_project_version_download_warnings();
CREATE OR REPLACE FUNCTION delete_old_project_version_unsafe_downloads() RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
DELETE FROM project_version_unsafe_downloads WHERE created_at < current_date - interval '30' day;
RETURN NEW;
END
$$;
CREATE OR REPLACE TRIGGER clean_old_project_version_unsafe_downloads
AFTER INSERT
ON project_version_unsafe_downloads
EXECUTE PROCEDURE delete_old_project_version_unsafe_downloads();
CREATE OR REPLACE FUNCTION update_project_name_trigger() RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE projects p SET name = u.name FROM users u WHERE p.id = new.id AND u.id = new.owner_id;
END;
$$;
CREATE OR REPLACE TRIGGER project_owner_name_updater
AFTER UPDATE
OF owner_id
ON projects
FOR EACH ROW
WHEN (old.owner_id <> new.owner_id)
EXECUTE PROCEDURE update_project_name_trigger();
CREATE OR REPLACE FUNCTION websearch_to_tsquery_postfix(dictionary regconfig, query text) RETURNS tsquery
IMMUTABLE
STRICT
LANGUAGE plpgsql
AS $$
DECLARE
arr TEXT[] := regexp_split_to_array(query, '\s+');
last TEXT := websearch_to_tsquery('simple', arr[array_length(arr, 1)])::TEXT;
init TSQUERY := websearch_to_tsquery(dictionary, regexp_replace(query, '\S+$', ''));
BEGIN
IF last = '' THEN
BEGIN
RETURN init && $2::TSQUERY;
EXCEPTION
WHEN SYNTAX_ERROR THEN
RETURN init && websearch_to_tsquery('');
END;
END IF;
RETURN init && (websearch_to_tsquery(dictionary, last) || to_tsquery('simple', last || ':*'));
END;
$$;

View File

@ -0,0 +1,106 @@
CREATE OR REPLACE MATERIALIZED VIEW home_projects AS
WITH tags AS (
SELECT sq.project_id,
sq.version_string,
sq.tag_name,
sq.tag_version,
sq.tag_color
FROM (SELECT pv.project_id,
pv.version_string,
pvt.name AS tag_name,
pvt.data AS tag_version,
pvt.platform_version,
pvt.color AS tag_color,
row_number()
OVER (PARTITION BY pv.project_id, pvt.platform_version ORDER BY pv.created_at DESC) AS row_num
FROM project_versions pv
JOIN (SELECT pvti.version_id,
pvti.name,
pvti.data,
CASE
WHEN pvti.name::text = 'Paper'::text THEN array_to_string(pvti.data, ', ')
WHEN pvti.name::text = 'Waterfall'::text THEN array_to_string(pvti.data, ', ')
WHEN pvti.name::text = 'Velocity'::text THEN array_to_string(pvti.data, ', ')
ELSE NULL::text
END AS platform_version,
pvti.color
FROM project_version_tags pvti
WHERE (pvti.name::text = ANY
(ARRAY ['Paper'::character varying, 'Waterfall'::character varying, 'Velocity'::character varying]::text[]))
AND pvti.data IS NOT NULL) pvt ON pv.id = pvt.version_id
WHERE pv.visibility = 0
AND (pvt.name::text = ANY
(ARRAY ['Paper'::character varying, 'Waterfall'::character varying, 'Velocity'::character varying]::text[]))
AND pvt.platform_version IS NOT NULL) sq
WHERE sq.row_num = 1
ORDER BY sq.platform_version DESC
)
SELECT p.id,
p.owner_name,
array_agg(DISTINCT pm.user_id) AS project_members,
p.slug,
p.visibility,
COALESCE(pva.views::bigint, 0::bigint) AS views,
COALESCE(pda.downloads::bigint, 0::bigint) AS downloads,
COALESCE(pvr.recent_views::bigint, 0::bigint) AS recent_views,
COALESCE(pdr.recent_downloads::bigint, 0::bigint) AS recent_downloads,
COALESCE(ps.stars::bigint, 0::bigint) AS stars,
COALESCE(pw.watchers::bigint, 0::bigint) AS watchers,
p.category,
p.description,
p.name,
p.created_at,
p.license_type,
max(lv.created_at) AS last_updated,
to_jsonb(ARRAY(SELECT jsonb_build_object('version_string', tags.version_string, 'tag_name', tags.tag_name,
'tag_version', tags.tag_version, 'tag_color',
tags.tag_color) AS jsonb_build_object
FROM tags
WHERE tags.project_id = p.id
LIMIT 5)) AS promoted_versions,
((setweight((to_tsvector('english'::regconfig, p.name::text) ||
to_tsvector('english'::regconfig, regexp_replace(p.name::text, '([a-z])([A-Z]+)'::text,
'\1_\2'::text, 'g'::text))), 'A'::"char") ||
setweight(to_tsvector('english'::regconfig, p.description::text), 'B'::"char")) ||
setweight(to_tsvector('english'::regconfig, array_to_string(p.keywords, ' '::text)), 'C'::"char")) || setweight(
to_tsvector('english'::regconfig, p.owner_name::text) || to_tsvector('english'::regconfig,
regexp_replace(
p.owner_name::text,
'([a-z])([A-Z]+)'::text,
'\1_\2'::text,
'g'::text)),
'D'::"char") AS search_words
FROM projects p
LEFT JOIN project_versions lv ON p.id = lv.project_id
JOIN project_members_all pm ON p.id = pm.id
LEFT JOIN (SELECT p_1.id,
COUNT(ps_1.user_id) AS stars
FROM projects p_1
LEFT JOIN project_stars ps_1 ON p_1.id = ps_1.project_id
GROUP BY p_1.id) ps ON p.id = ps.id
LEFT JOIN (SELECT p_1.id,
count(pw_1.user_id) AS watchers
FROM projects p_1
LEFT JOIN project_watchers pw_1 ON p_1.id = pw_1.project_id
GROUP BY p_1.id) pw ON p.id = pw.id
LEFT JOIN (SELECT pv.project_id,
sum(pv.views) AS views
FROM project_views pv
GROUP BY pv.project_id) pva ON p.id = pva.project_id
LEFT JOIN (SELECT pv.project_id,
sum(pv.downloads) AS downloads
FROM project_versions_downloads pv
GROUP BY pv.project_id) pda ON p.id = pda.project_id
LEFT JOIN (SELECT pv.project_id,
sum(pv.views) AS recent_views
FROM project_views pv
WHERE pv.day >= (CURRENT_DATE - '30 days'::interval)
AND pv.day <= CURRENT_DATE
GROUP BY pv.project_id) pvr ON p.id = pvr.project_id
LEFT JOIN (SELECT pv.project_id,
sum(pv.downloads) AS recent_downloads
FROM project_versions_downloads pv
WHERE pv.day >= (CURRENT_DATE - '30 days'::interval)
AND pv.day <= CURRENT_DATE
GROUP BY pv.project_id) pdr ON p.id = pdr.project_id
GROUP BY p.id, ps.stars, pw.watchers, pva.views, pda.downloads, pvr.recent_views, pdr.recent_downloads;

View File

@ -0,0 +1,131 @@
CREATE VIEW v_logged_actions(id, created_at, user_id, user_name, address, action, context_type, new_state, old_state, p_id, p_slug, p_owner_name, pv_id, pv_version_string, pv_platforms, pp_id, pp_name, pp_slug, s_id, s_name) AS
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
0 AS context_type,
a.new_state,
a.old_state,
p.id AS p_id,
p.slug AS p_slug,
ou.name AS p_owner_name,
NULL::bigint AS pv_id,
NULL::character varying(255) AS pv_version_string,
NULL::bigint[] AS pv_platforms,
NULL::bigint AS pp_id,
NULL::character varying(255) AS pp_name,
NULL::character varying(255) AS pp_slug,
NULL::bigint AS s_id,
NULL::character varying(255) AS s_name
FROM logged_actions_project a
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN projects p ON a.project_id = p.id
LEFT JOIN users ou ON p.owner_id = ou.id
UNION ALL
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
1 AS context_type,
a.new_state,
a.old_state,
p.id AS p_id,
p.slug AS p_slug,
ou.name AS p_owner_name,
pv.id AS pv_id,
pv.version_string AS pv_version_string,
array(SELECT DISTINCT plv.platform
FROM project_version_platform_dependencies pvpd
JOIN platform_versions plv ON pvpd.platform_version_id = plv.id
WHERE pv.id = pvpd.version_id
ORDER BY plv.platform
) AS pv_platforms,
NULL::bigint AS pp_id,
NULL::character varying AS pp_name,
NULL::character varying AS pp_slug,
NULL::bigint AS s_id,
NULL::character varying AS s_name
FROM logged_actions_version a
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN project_versions pv ON a.version_id = pv.id
LEFT JOIN projects p ON a.project_id = p.id
LEFT JOIN users ou ON p.owner_id = ou.id
UNION ALL
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
2 AS context_type,
a.new_state,
a.old_state,
p.id AS p_id,
p.slug AS p_slug,
ou.name AS p_owner_name,
NULL::bigint AS pv_id,
NULL::character varying AS pv_version_string,
NULL::bigint[] AS pv_platforms,
pp.id AS pp_id,
pp.name AS pp_name,
pp.slug AS pp_slug,
NULL::bigint AS s_id,
NULL::character varying AS s_name
FROM logged_actions_page a
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN project_pages pp ON a.page_id = pp.id
LEFT JOIN projects p ON a.project_id = p.id
LEFT JOIN users ou ON p.owner_id = ou.id
UNION ALL
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
3 AS context_type,
a.new_state,
a.old_state,
NULL::bigint AS p_id,
NULL::character varying AS p_slug,
NULL::character varying AS p_owner_name,
NULL::bigint AS pv_id,
NULL::character varying AS pv_version_string,
NULL::bigint[] AS pv_platforms,
NULL::bigint AS pp_id,
NULL::character varying AS pp_name,
NULL::character varying AS pp_slug,
s.id AS s_id,
s.name AS s_name
FROM logged_actions_user a
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN users s ON a.subject_id = s.id
UNION ALL
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
4 AS context_type,
a.new_state,
a.old_state,
NULL::bigint AS p_id,
NULL::character varying AS p_slug,
NULL::character varying AS p_owner_name,
NULL::bigint AS pv_id,
NULL::character varying AS pv_version_string,
NULL::bigint[] AS pv_platforms,
NULL::bigint AS pp_id,
NULL::character varying AS pp_name,
NULL::character varying AS pp_slug,
s.id AS s_id,
s.name AS s_name
FROM logged_actions_organization a
LEFT JOIN organizations o ON a.organization_id = o.id
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN users s ON o.user_id = s.id;

View File

@ -0,0 +1,42 @@
CREATE OR REPLACE VIEW pinned_versions AS
SELECT * FROM (
SELECT DISTINCT ON (version_id) version_id,
id,
created_at,
type,
version_string,
platforms,
project_id
FROM (
SELECT ppv.id,
ppv.version_id,
pv.created_at,
pv.version_string,
array(SELECT DISTINCT plv.platform FROM project_version_platform_dependencies pvpd
JOIN platform_versions plv ON plv.id = pvpd.platform_version_id
WHERE pvpd.version_id = pv.id
ORDER BY plv.platform
) AS platforms,
'version' AS type,
pv.project_id
FROM pinned_project_versions ppv
JOIN project_versions pv ON pv.id = ppv.version_id
UNION ALL
(SELECT pc.id,
pv.id AS version_id,
pv.created_at,
pv.version_string,
array(SELECT DISTINCT plv.platform FROM project_version_platform_dependencies pvpd
JOIN platform_versions plv ON plv.id = pvpd.platform_version_id
WHERE pvpd.version_id = pv.id
ORDER BY plv.platform
) AS platforms,
'channel' as type,
pv.project_id
FROM project_channels pc
JOIN project_versions pv ON pc.id = pv.channel_id
WHERE 3 = ANY(pc.flags)
ORDER BY pv.created_at DESC
LIMIT 1)
) AS pvs
) AS t ORDER BY t.created_at DESC;

View File

@ -0,0 +1,37 @@
CREATE VIEW global_trust(user_id, permission) AS
SELECT gr.user_id,
COALESCE(bit_or(r.permission), '0'::bit(64)) AS permission
FROM user_global_roles gr
JOIN roles r ON gr.role_id = r.id
GROUP BY gr.user_id;
CREATE VIEW project_trust(project_id, user_id, permission) AS
SELECT pm.project_id,
pm.user_id,
COALESCE(bit_or(r.permission), '0'::bit(64)) AS permission
FROM project_members pm
JOIN user_project_roles rp ON pm.project_id = rp.project_id AND pm.user_id = rp.user_id AND rp.accepted
JOIN roles r ON rp.role_type::text = r.name::text
GROUP BY pm.project_id, pm.user_id;
CREATE VIEW organization_trust(organization_id, user_id, permission) AS
SELECT om.organization_id,
om.user_id,
COALESCE(bit_or(r.permission), '0'::bit(64)) AS permission
FROM organization_members om
JOIN user_organization_roles ro
ON om.organization_id = ro.organization_id AND om.user_id = ro.user_id AND ro.accepted
JOIN roles r ON ro.role_type::text = r.name::text
GROUP BY om.organization_id, om.user_id;
CREATE VIEW project_members_all(id, user_id) AS
SELECT p.id,
pm.user_id
FROM projects p
LEFT JOIN project_members pm ON p.id = pm.project_id
UNION
SELECT p.id,
om.user_id
FROM projects p
LEFT JOIN organization_members om ON p.owner_id = om.organization_id
WHERE om.user_id IS NOT NULL;

View File

@ -914,389 +914,3 @@ CREATE TABLE pinned_project_versions
CONSTRAINT pinned_project_versions_project_version_key
UNIQUE (project_id, version_id)
);
CREATE VIEW project_members_all(id, user_id) AS
SELECT p.id,
pm.user_id
FROM projects p
LEFT JOIN project_members pm ON p.id = pm.project_id
UNION
SELECT p.id,
om.user_id
FROM projects p
LEFT JOIN organization_members om ON p.owner_id = om.organization_id
WHERE om.user_id IS NOT NULL;
CREATE OR REPLACE VIEW pinned_versions AS
SELECT * FROM (
SELECT DISTINCT ON (version_id) version_id,
id,
created_at,
type,
version_string,
platforms,
project_id
FROM (
SELECT ppv.id,
ppv.version_id,
pv.created_at,
pv.version_string,
array(SELECT DISTINCT plv.platform FROM project_version_platform_dependencies pvpd
JOIN platform_versions plv ON plv.id = pvpd.platform_version_id
WHERE pvpd.version_id = pv.id
ORDER BY plv.platform
) AS platforms,
'version' AS type,
pv.project_id
FROM pinned_project_versions ppv
JOIN project_versions pv ON pv.id = ppv.version_id
UNION ALL
(SELECT pc.id,
pv.id AS version_id,
pv.created_at,
pv.version_string,
array(SELECT DISTINCT plv.platform FROM project_version_platform_dependencies pvpd
JOIN platform_versions plv ON plv.id = pvpd.platform_version_id
WHERE pvpd.version_id = pv.id
ORDER BY plv.platform
) AS platforms,
'channel' as type,
pv.project_id
FROM project_channels pc
JOIN project_versions pv ON pc.id = pv.channel_id
WHERE 3 = ANY(pc.flags)
ORDER BY pv.created_at DESC
LIMIT 1)
) AS pvs
) AS t ORDER BY t.created_at DESC;
CREATE MATERIALIZED VIEW home_projects AS
WITH tags AS (
SELECT sq.project_id,
sq.version_string,
sq.tag_name,
sq.tag_version,
sq.tag_color
FROM (SELECT pv.project_id,
pv.version_string,
pvt.name AS tag_name,
pvt.data AS tag_version,
pvt.platform_version,
pvt.color AS tag_color,
row_number()
OVER (PARTITION BY pv.project_id, pvt.platform_version ORDER BY pv.created_at DESC) AS row_num
FROM project_versions pv
JOIN (SELECT pvti.version_id,
pvti.name,
pvti.data,
CASE
WHEN pvti.name::text = 'Paper'::text THEN array_to_string(pvti.data, ', ')
WHEN pvti.name::text = 'Waterfall'::text THEN array_to_string(pvti.data, ', ')
WHEN pvti.name::text = 'Velocity'::text THEN array_to_string(pvti.data, ', ')
ELSE NULL::text
END AS platform_version,
pvti.color
FROM project_version_tags pvti
WHERE (pvti.name::text = ANY
(ARRAY ['Paper'::character varying, 'Waterfall'::character varying, 'Velocity'::character varying]::text[]))
AND pvti.data IS NOT NULL) pvt ON pv.id = pvt.version_id
WHERE pv.visibility = 0
AND (pvt.name::text = ANY
(ARRAY ['Paper'::character varying, 'Waterfall'::character varying, 'Velocity'::character varying]::text[]))
AND pvt.platform_version IS NOT NULL) sq
WHERE sq.row_num = 1
ORDER BY sq.platform_version DESC
)
SELECT p.id,
p.owner_name,
array_agg(DISTINCT pm.user_id) AS project_members,
p.slug,
p.visibility,
COALESCE(pva.views::bigint, 0::bigint) AS views,
COALESCE(pda.downloads::bigint, 0::bigint) AS downloads,
COALESCE(pvr.recent_views::bigint, 0::bigint) AS recent_views,
COALESCE(pdr.recent_downloads::bigint, 0::bigint) AS recent_downloads,
COALESCE(ps.stars::bigint, 0::bigint) AS stars,
COALESCE(pw.watchers::bigint, 0::bigint) AS watchers,
p.category,
p.description,
p.name,
p.created_at,
p.license_type,
max(lv.created_at) AS last_updated,
to_jsonb(ARRAY(SELECT jsonb_build_object('version_string', tags.version_string, 'tag_name', tags.tag_name,
'tag_version', tags.tag_version, 'tag_color',
tags.tag_color) AS jsonb_build_object
FROM tags
WHERE tags.project_id = p.id
LIMIT 5)) AS promoted_versions,
((setweight((to_tsvector('english'::regconfig, p.name::text) ||
to_tsvector('english'::regconfig, regexp_replace(p.name::text, '([a-z])([A-Z]+)'::text,
'\1_\2'::text, 'g'::text))), 'A'::"char") ||
setweight(to_tsvector('english'::regconfig, p.description::text), 'B'::"char")) ||
setweight(to_tsvector('english'::regconfig, array_to_string(p.keywords, ' '::text)), 'C'::"char")) || setweight(
to_tsvector('english'::regconfig, p.owner_name::text) || to_tsvector('english'::regconfig,
regexp_replace(
p.owner_name::text,
'([a-z])([A-Z]+)'::text,
'\1_\2'::text,
'g'::text)),
'D'::"char") AS search_words
FROM projects p
LEFT JOIN project_versions lv ON p.id = lv.project_id
JOIN project_members_all pm ON p.id = pm.id
LEFT JOIN (SELECT p_1.id,
COUNT(ps_1.user_id) AS stars
FROM projects p_1
LEFT JOIN project_stars ps_1 ON p_1.id = ps_1.project_id
GROUP BY p_1.id) ps ON p.id = ps.id
LEFT JOIN (SELECT p_1.id,
count(pw_1.user_id) AS watchers
FROM projects p_1
LEFT JOIN project_watchers pw_1 ON p_1.id = pw_1.project_id
GROUP BY p_1.id) pw ON p.id = pw.id
LEFT JOIN (SELECT pv.project_id,
sum(pv.views) AS views
FROM project_views pv
GROUP BY pv.project_id) pva ON p.id = pva.project_id
LEFT JOIN (SELECT pv.project_id,
sum(pv.downloads) AS downloads
FROM project_versions_downloads pv
GROUP BY pv.project_id) pda ON p.id = pda.project_id
LEFT JOIN (SELECT pv.project_id,
sum(pv.views) AS recent_views
FROM project_views pv
WHERE pv.day >= (CURRENT_DATE - '30 days'::interval)
AND pv.day <= CURRENT_DATE
GROUP BY pv.project_id) pvr ON p.id = pvr.project_id
LEFT JOIN (SELECT pv.project_id,
sum(pv.downloads) AS recent_downloads
FROM project_versions_downloads pv
WHERE pv.day >= (CURRENT_DATE - '30 days'::interval)
AND pv.day <= CURRENT_DATE
GROUP BY pv.project_id) pdr ON p.id = pdr.project_id
GROUP BY p.id, ps.stars, pw.watchers, pva.views, pda.downloads, pvr.recent_views, pdr.recent_downloads;
CREATE VIEW global_trust(user_id, permission) AS
SELECT gr.user_id,
COALESCE(bit_or(r.permission), '0'::bit(64)) AS permission
FROM user_global_roles gr
JOIN roles r ON gr.role_id = r.id
GROUP BY gr.user_id;
CREATE VIEW project_trust(project_id, user_id, permission) AS
SELECT pm.project_id,
pm.user_id,
COALESCE(bit_or(r.permission), '0'::bit(64)) AS permission
FROM project_members pm
JOIN user_project_roles rp ON pm.project_id = rp.project_id AND pm.user_id = rp.user_id AND rp.accepted
JOIN roles r ON rp.role_type::text = r.name::text
GROUP BY pm.project_id, pm.user_id;
CREATE VIEW organization_trust(organization_id, user_id, permission) AS
SELECT om.organization_id,
om.user_id,
COALESCE(bit_or(r.permission), '0'::bit(64)) AS permission
FROM organization_members om
JOIN user_organization_roles ro
ON om.organization_id = ro.organization_id AND om.user_id = ro.user_id AND ro.accepted
JOIN roles r ON ro.role_type::text = r.name::text
GROUP BY om.organization_id, om.user_id;
CREATE VIEW v_logged_actions(id, created_at, user_id, user_name, address, action, context_type, new_state, old_state, p_id, p_slug, p_owner_name, pv_id, pv_version_string, pv_platforms, pp_id, pp_name, pp_slug, s_id, s_name) AS
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
0 AS context_type,
a.new_state,
a.old_state,
p.id AS p_id,
p.slug AS p_slug,
ou.name AS p_owner_name,
NULL::bigint AS pv_id,
NULL::character varying(255) AS pv_version_string,
NULL::bigint[] AS pv_platforms,
NULL::bigint AS pp_id,
NULL::character varying(255) AS pp_name,
NULL::character varying(255) AS pp_slug,
NULL::bigint AS s_id,
NULL::character varying(255) AS s_name
FROM logged_actions_project a
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN projects p ON a.project_id = p.id
LEFT JOIN users ou ON p.owner_id = ou.id
UNION ALL
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
1 AS context_type,
a.new_state,
a.old_state,
p.id AS p_id,
p.slug AS p_slug,
ou.name AS p_owner_name,
pv.id AS pv_id,
pv.version_string AS pv_version_string,
array(SELECT DISTINCT plv.platform
FROM project_version_platform_dependencies pvpd
JOIN platform_versions plv ON pvpd.platform_version_id = plv.id
WHERE pv.id = pvpd.version_id
ORDER BY plv.platform
) AS pv_platforms,
NULL::bigint AS pp_id,
NULL::character varying AS pp_name,
NULL::character varying AS pp_slug,
NULL::bigint AS s_id,
NULL::character varying AS s_name
FROM logged_actions_version a
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN project_versions pv ON a.version_id = pv.id
LEFT JOIN projects p ON a.project_id = p.id
LEFT JOIN users ou ON p.owner_id = ou.id
UNION ALL
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
2 AS context_type,
a.new_state,
a.old_state,
p.id AS p_id,
p.slug AS p_slug,
ou.name AS p_owner_name,
NULL::bigint AS pv_id,
NULL::character varying AS pv_version_string,
NULL::bigint[] AS pv_platforms,
pp.id AS pp_id,
pp.name AS pp_name,
pp.slug AS pp_slug,
NULL::bigint AS s_id,
NULL::character varying AS s_name
FROM logged_actions_page a
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN project_pages pp ON a.page_id = pp.id
LEFT JOIN projects p ON a.project_id = p.id
LEFT JOIN users ou ON p.owner_id = ou.id
UNION ALL
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
3 AS context_type,
a.new_state,
a.old_state,
NULL::bigint AS p_id,
NULL::character varying AS p_slug,
NULL::character varying AS p_owner_name,
NULL::bigint AS pv_id,
NULL::character varying AS pv_version_string,
NULL::bigint[] AS pv_platforms,
NULL::bigint AS pp_id,
NULL::character varying AS pp_name,
NULL::character varying AS pp_slug,
s.id AS s_id,
s.name AS s_name
FROM logged_actions_user a
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN users s ON a.subject_id = s.id
UNION ALL
SELECT a.id,
a.created_at,
a.user_id,
u.name AS user_name,
a.address,
a.action,
4 AS context_type,
a.new_state,
a.old_state,
NULL::bigint AS p_id,
NULL::character varying AS p_slug,
NULL::character varying AS p_owner_name,
NULL::bigint AS pv_id,
NULL::character varying AS pv_version_string,
NULL::bigint[] AS pv_platforms,
NULL::bigint AS pp_id,
NULL::character varying AS pp_name,
NULL::character varying AS pp_slug,
s.id AS s_id,
s.name AS s_name
FROM logged_actions_organization a
LEFT JOIN organizations o ON a.organization_id = o.id
LEFT JOIN users u ON a.user_id = u.id
LEFT JOIN users s ON o.user_id = s.id;
CREATE FUNCTION delete_old_project_version_download_warnings() RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
DELETE FROM project_version_download_warnings WHERE created_at < current_date - interval '30' day;
RETURN NEW;
END
$$;
CREATE TRIGGER clean_old_project_version_download_warnings
AFTER INSERT
ON project_version_download_warnings
EXECUTE PROCEDURE delete_old_project_version_download_warnings();
CREATE FUNCTION delete_old_project_version_unsafe_downloads() RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
DELETE FROM project_version_unsafe_downloads WHERE created_at < current_date - interval '30' day;
RETURN NEW;
END
$$;
CREATE TRIGGER clean_old_project_version_unsafe_downloads
AFTER INSERT
ON project_version_unsafe_downloads
EXECUTE PROCEDURE delete_old_project_version_unsafe_downloads();
CREATE FUNCTION update_project_name_trigger() RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
BEGIN
UPDATE projects p SET name = u.name FROM users u WHERE p.id = new.id AND u.id = new.owner_id;
END;
$$;
CREATE TRIGGER project_owner_name_updater
AFTER UPDATE
OF owner_id
ON projects
FOR EACH ROW
WHEN (old.owner_id <> new.owner_id)
EXECUTE PROCEDURE update_project_name_trigger();
CREATE FUNCTION websearch_to_tsquery_postfix(dictionary regconfig, query text) RETURNS tsquery
IMMUTABLE
STRICT
LANGUAGE plpgsql
AS $$
DECLARE
arr TEXT[] := regexp_split_to_array(query, '\s+');
last TEXT := websearch_to_tsquery('simple', arr[array_length(arr, 1)])::TEXT;
init TSQUERY := websearch_to_tsquery(dictionary, regexp_replace(query, '\S+$', ''));
BEGIN
IF last = '' THEN
BEGIN
RETURN init && $2::TSQUERY;
EXCEPTION
WHEN SYNTAX_ERROR THEN
RETURN init && websearch_to_tsquery('');
END;
END IF;
RETURN init && (websearch_to_tsquery(dictionary, last) || to_tsquery('simple', last || ':*'));
END;
$$;