chore(db): flatten migrations and rename repeatables in order

This commit is contained in:
MiniDigger | Martin 2022-11-06 20:31:49 +01:00
parent 393daca489
commit d65514cd0e
17 changed files with 78 additions and 366 deletions

View File

@ -1,11 +1,11 @@
CREATE VIEW global_trust(user_id, permission) AS
CREATE OR REPLACE 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
CREATE OR REPLACE 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
@ -14,7 +14,7 @@ FROM project_members pm
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
CREATE OR REPLACE 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
@ -24,7 +24,7 @@ FROM organization_members om
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
CREATE OR REPLACE VIEW project_members_all(id, user_id) AS
SELECT p.id,
pm.user_id
FROM projects p

View File

@ -1,4 +1,4 @@
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
CREATE OR REPLACE 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,

View File

@ -1,6 +1,4 @@
DROP MATERIALIZED VIEW home_projects;
DROP TABLE recommended_project_versions;
DROP TABLE project_version_tags;
DROP MATERIALIZED VIEW IF EXISTS home_projects CASCADE;
CREATE MATERIALIZED VIEW home_projects AS
SELECT p.id,

View File

@ -1,106 +0,0 @@
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

@ -1,42 +0,0 @@
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

@ -222,12 +222,6 @@ CREATE TABLE project_versions
CONSTRAINT versions_channel_id_fkey
REFERENCES project_channels
ON DELETE CASCADE,
file_size bigint default 1
CONSTRAINT versions_file_size_check
CHECK (file_size > 0),
hash varchar(32),
file_name varchar(255),
external_url varchar(255),
reviewer_id bigint
CONSTRAINT project_versions_reviewer_id_fkey
REFERENCES users
@ -240,31 +234,14 @@ CREATE TABLE project_versions
visibility integer DEFAULT 1 NOT NULL,
review_state integer DEFAULT 0 NOT NULL,
create_forum_post boolean NOT NULL,
post_id integer
post_id integer,
CONSTRAINT version_string_unique
UNIQUE(project_id, version_string)
);
CREATE INDEX project_version_version_string_idx
ON project_versions (version_string);
CREATE TABLE recommended_project_versions
(
id bigserial NOT NULL
CONSTRAINT recommended_project_versions_pkey
PRIMARY KEY,
created_at timestamp with time zone NOT NULL,
version_id bigint NOT NULL
CONSTRAINT recommended_project_versions_version_id_fkey
REFERENCES project_versions
ON DELETE CASCADE,
project_id bigint NOT NULL
CONSTRAINT recommended_project_versions_project_id_fkey
REFERENCES projects
ON DELETE CASCADE,
platform bigint NOT NULL,
CONSTRAINT recommended_project_versions_unique
UNIQUE (project_id, platform)
);
CREATE TABLE platform_versions
(
id bigserial NOT NULL
@ -316,6 +293,40 @@ CREATE TABLE project_version_platform_dependencies
UNIQUE (version_id, platform_version_id)
);
CREATE TABLE project_version_downloads
(
id bigserial NOT NULL PRIMARY KEY,
version_id bigint NOT NULL,
file_size bigint default 1
CONSTRAINT versions_file_size_check
CHECK (file_size > 0),
hash varchar(32),
file_name varchar(255),
external_url varchar(255),
CONSTRAINT project_version_downloads_version_id_fkey
FOREIGN KEY (version_id)
REFERENCES project_versions
ON DELETE CASCADE
);
CREATE TABLE project_version_platform_downloads
(
id bigserial NOT NULL PRIMARY KEY,
version_id bigint NOT NULL,
platform bigint NOT NULL,
download_id bigint NOT NULL,
CONSTRAINT project_version_platform_downloads_version_id_fkey
FOREIGN KEY (version_id)
REFERENCES project_versions
ON DELETE CASCADE,
CONSTRAINT project_version_platform_downloads_download_id_fkey
FOREIGN KEY (download_id)
REFERENCES project_version_downloads
ON DELETE CASCADE,
CONSTRAINT project_version_platform_downloads_unique
UNIQUE (version_id, platform)
);
CREATE TABLE roles
(
id bigint NOT NULL
@ -400,6 +411,23 @@ CREATE TABLE notifications
message_args varchar(255) [] NOT NULL
);
CREATE TABLE project_flag_notifications
(
id bigserial NOT NULL
CONSTRAINT project_flag_notifications_pkey
PRIMARY KEY,
flag_id bigint NOT NULL
CONSTRAINT project_flag_notifications_flag_id_fkey
REFERENCES project_flags
ON DELETE CASCADE,
notification_id bigint NOT NULL
CONSTRAINT project_flag_notifications_notification_id_fkey
REFERENCES notifications
ON DELETE CASCADE,
CONSTRAINT project_flag_notifications_notification_key
UNIQUE (notification_id)
);
CREATE TABLE project_watchers
(
project_id bigint NOT NULL
@ -616,28 +644,6 @@ CREATE TABLE project_version_visibility_changes
visibility integer NOT NULL
);
CREATE TABLE project_version_tags
(
id bigserial NOT NULL
CONSTRAINT project_version_tags_pkey
PRIMARY KEY,
created_at timestamp with time zone DEFAULT now() NOT NULL,
version_id bigint NOT NULL
CONSTRAINT project_version_tags_version_id_fkey
REFERENCES project_versions
ON DELETE CASCADE,
name varchar(255) NOT NULL,
data varchar(255)[],
color integer NOT NULL,
CONSTRAINT project_version_tags_unique UNIQUE (version_id, name)
);
CREATE INDEX projects_versions_tags_version_id
ON project_version_tags (version_id);
-- CREATE INDEX project_version_tags_name_data_idx
-- ON project_version_tags (name, data);
CREATE TABLE user_global_roles
(
user_id bigint NOT NULL
@ -914,3 +920,20 @@ CREATE TABLE pinned_project_versions
CONSTRAINT pinned_project_versions_project_version_key
UNIQUE (project_id, version_id)
);
CREATE TABLE pinned_user_projects
(
id bigserial NOT NULL
CONSTRAINT project_pinned_pkey
PRIMARY KEY,
user_id bigint NOT NULL
CONSTRAINT project_pinned_user_id_fkey
REFERENCES users
ON DELETE CASCADE,
project_id bigint NOT NULL
CONSTRAINT project_pinned_project_id_fkey
REFERENCES projects
ON DELETE CASCADE,
CONSTRAINT pinned_projects_project_user_key
UNIQUE (project_id, user_id)
);

View File

@ -1,58 +0,0 @@
CREATE TABLE pinned_user_projects
(
id bigserial NOT NULL
CONSTRAINT project_pinned_pkey
PRIMARY KEY,
user_id bigint NOT NULL
CONSTRAINT project_pinned_user_id_fkey
REFERENCES users
ON DELETE CASCADE,
project_id bigint NOT NULL
CONSTRAINT project_pinned_project_id_fkey
REFERENCES projects
ON DELETE CASCADE,
CONSTRAINT pinned_projects_project_user_key
UNIQUE (project_id, user_id)
);
CREATE OR REPLACE VIEW pinned_projects AS
SELECT *
FROM (SELECT DISTINCT ON (project_id) project_id,
user_id,
id,
owner_name as owner,
project_members,
slug,
visibility,
views,
downloads,
recent_views,
recent_downloads,
stars,
watchers,
category,
name,
created_at,
license_type,
last_updated
FROM (SELECT pp.id,
pp.user_id,
pp.project_id,
hp.owner_name,
hp.project_members,
hp.slug,
hp.visibility,
hp.views,
hp.downloads,
hp.recent_views,
hp.recent_downloads,
hp.stars,
hp.watchers,
hp.category,
hp.name,
hp.created_at,
hp.license_type,
hp.last_updated
FROM pinned_user_projects pp
JOIN home_projects hp ON hp.id = pp.project_id
JOIN projects p on pp.project_id = p.id) AS pvs) as t;

View File

@ -1,20 +0,0 @@
CREATE TABLE project_flag_notifications
(
id bigserial NOT NULL
CONSTRAINT project_flag_notifications_pkey
PRIMARY KEY,
flag_id bigint NOT NULL
CONSTRAINT project_flag_notifications_flag_id_fkey
REFERENCES project_flags
ON DELETE CASCADE,
notification_id bigint NOT NULL
CONSTRAINT project_flag_notifications_notification_id_fkey
REFERENCES notifications
ON DELETE CASCADE,
user_id bigint NOT NULL
CONSTRAINT project_flag_notifications_user_id_fkey
REFERENCES users
ON DELETE CASCADE,
CONSTRAINT project_flag_notifications_notification_key
UNIQUE (notification_id)
);

View File

@ -1 +0,0 @@
ALTER TABLE project_flag_notifications DROP COLUMN user_id;

View File

@ -1,41 +0,0 @@
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)) AS pvs) AS t
ORDER BY t.created_at DESC;

View File

@ -1,37 +0,0 @@
TRUNCATE TABLE projects CASCADE;
ALTER TABLE project_versions ADD CONSTRAINT version_string_unique UNIQUE(project_id, version_string);
CREATE TABLE project_version_downloads
(
id bigserial NOT NULL PRIMARY KEY,
version_id bigint NOT NULL,
file_size bigint default 1
CONSTRAINT versions_file_size_check
CHECK (file_size > 0),
hash varchar(32),
file_name varchar(255),
external_url varchar(255),
CONSTRAINT project_version_downloads_version_id_fkey
FOREIGN KEY (version_id)
REFERENCES project_versions
ON DELETE CASCADE
);
CREATE TABLE project_version_platform_downloads
(
id bigserial NOT NULL PRIMARY KEY,
version_id bigint NOT NULL,
platform bigint NOT NULL,
download_id bigint NOT NULL,
CONSTRAINT project_version_platform_downloads_version_id_fkey
FOREIGN KEY (version_id)
REFERENCES project_versions
ON DELETE CASCADE,
CONSTRAINT project_version_platform_downloads_download_id_fkey
FOREIGN KEY (download_id)
REFERENCES project_version_downloads
ON DELETE CASCADE,
CONSTRAINT project_version_platform_downloads_unique
UNIQUE (version_id, platform)
);

View File

@ -1,4 +0,0 @@
ALTER TABLE project_versions DROP COLUMN external_url;
ALTER TABLE project_versions DROP COLUMN hash;
ALTER TABLE project_versions DROP COLUMN file_name;
ALTER TABLE project_versions DROP COLUMN file_size;

@ -1 +1 @@
Subproject commit 32e402d11c4eb6d9ca4077d2a9eba5d0c30471ac
Subproject commit 4dc74966aa6df91a73adb2876662cefc5d5aeb79