-
Notifications
You must be signed in to change notification settings - Fork 6
Pm 2206 master #38
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
Pm 2206 master #38
Changes from all commits
File filter
Filter by extension
Conversations
Jump to
Diff view
Diff view
There are no files selected for viewing
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -1,13 +1,66 @@ | ||
| -- Add indexes to support faster `/v6/my-reviews` queries. | ||
|
|
||
| CREATE EXTENSION IF NOT EXISTS pg_trgm; | ||
| CREATE SCHEMA IF NOT EXISTS skills; | ||
| CREATE SCHEMA IF NOT EXISTS reviews; | ||
|
|
||
| CREATE EXTENSION IF NOT EXISTS fuzzystrmatch WITH SCHEMA skills; | ||
| CREATE EXTENSION IF NOT EXISTS pg_trgm WITH SCHEMA pg_catalog; | ||
| CREATE EXTENSION IF NOT EXISTS pgcrypto WITH SCHEMA reviews; | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. [💡 |
||
| CREATE EXTENSION IF NOT EXISTS "uuid-ossp" WITH SCHEMA skills; | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. [💡 |
||
|
|
||
| CREATE INDEX IF NOT EXISTS "challenge_status_type_track_created_at_idx" | ||
| ON "Challenge" ("status", "typeId", "trackId", "createdAt" DESC); | ||
|
|
||
| DROP INDEX IF EXISTS "challenge_name_idx"; | ||
|
|
||
| CREATE INDEX IF NOT EXISTS "challenge_name_trgm_idx" | ||
| ON "Challenge" USING gin ("name" pg_catalog.gin_trgm_ops); | ||
|
|
||
| DO | ||
| $$ | ||
| DECLARE | ||
| challenge_phase_schema TEXT; | ||
| BEGIN | ||
| SELECT n.nspname | ||
| INTO challenge_phase_schema | ||
| FROM pg_class c | ||
| JOIN pg_namespace n ON n.oid = c.relnamespace | ||
| WHERE c.relname = 'ChallengePhase' | ||
| AND c.relkind = 'r' | ||
| LIMIT 1; | ||
|
|
||
| IF challenge_phase_schema IS NULL THEN | ||
| RETURN; | ||
| END IF; | ||
|
|
||
| IF NOT EXISTS ( | ||
| SELECT 1 | ||
| FROM pg_class idx | ||
| JOIN pg_namespace ns ON ns.oid = idx.relnamespace | ||
| WHERE idx.relname = 'challenge_phase_order_idx' | ||
| AND ns.nspname = challenge_phase_schema | ||
| ) | ||
| AND EXISTS ( | ||
| SELECT 1 | ||
| FROM pg_class idx | ||
| JOIN pg_namespace ns ON ns.oid = idx.relnamespace | ||
| WHERE idx.relname = 'challenge_phase_challenge_open_end_idx' | ||
| AND ns.nspname = challenge_phase_schema | ||
| AND pg_get_indexdef(idx.oid) LIKE '%("challengeId", "isOpen", "scheduledEndDate", "actualEndDate", name)%' | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. [ |
||
| ) | ||
| THEN | ||
| EXECUTE format( | ||
| 'ALTER INDEX %I.%I RENAME TO %I', | ||
| challenge_phase_schema, | ||
| 'challenge_phase_challenge_open_end_idx', | ||
| 'challenge_phase_order_idx' | ||
| ); | ||
| END IF; | ||
| END | ||
| $$ LANGUAGE plpgsql; | ||
|
|
||
| CREATE INDEX IF NOT EXISTS "challenge_phase_challenge_open_end_idx" | ||
| ON "ChallengePhase" ("challengeId", "isOpen", "scheduledEndDate", "actualEndDate"); | ||
|
|
||
| CREATE INDEX IF NOT EXISTS "challenge_name_trgm_idx" | ||
| ON "Challenge" | ||
| USING gin ("name" pg_catalog.gin_trgm_ops); | ||
| CREATE INDEX IF NOT EXISTS "challenge_phase_order_idx" | ||
| ON "ChallengePhase" ("challengeId", "isOpen", "scheduledEndDate", "actualEndDate", "name"); | ||
| Original file line number | Diff line number | Diff line change |
|---|---|---|
| @@ -0,0 +1,30 @@ | ||
| -- View to use in performance updates (PM-2206) | ||
| DROP VIEW IF EXISTS "challenges"."MemberChallengeAccess"; | ||
|
|
||
| DO $$ | ||
| BEGIN | ||
| IF EXISTS ( | ||
| SELECT 1 | ||
| FROM information_schema.tables | ||
| WHERE table_schema = 'resources' | ||
| AND table_name = 'Resource' | ||
| ) THEN | ||
| EXECUTE format( | ||
| 'CREATE VIEW %I.%I AS | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. [ |
||
| SELECT DISTINCT r."challengeId", r."memberId" | ||
| FROM resources."Resource" r | ||
| WHERE r."challengeId" IS NOT NULL | ||
| AND r."memberId" IS NOT NULL', | ||
| current_schema(), 'MemberChallengeAccess' | ||
| ); | ||
| ELSE | ||
| EXECUTE format( | ||
| 'CREATE VIEW %I.%I AS | ||
| SELECT CAST(NULL AS TEXT) AS "challengeId", | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. [ |
||
| CAST(NULL AS TEXT) AS "memberId" | ||
| WHERE FALSE', | ||
| current_schema(), 'MemberChallengeAccess' | ||
| ); | ||
| END IF; | ||
| END; | ||
| $$; | ||
| Original file line number | Diff line number | Diff line change |
|---|---|---|
|
|
@@ -127,6 +127,7 @@ model Challenge { | |
| terms ChallengeTerm[] | ||
| skills ChallengeSkill[] | ||
| auditLogs AuditLog[] | ||
| memberAccesses MemberChallengeAccess[] | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. [ |
||
|
|
||
| // Relation to ChallengeType (FK: typeId) | ||
| type ChallengeType @relation(fields: [typeId], references: [id]) | ||
|
|
@@ -161,6 +162,20 @@ model Challenge { | |
| @@index([projectId, status]) | ||
| } | ||
|
|
||
| ////////////////////////////////////////// | ||
| // MemberChallengeAccess view – member/challenge pairs from resources schema | ||
| ////////////////////////////////////////// | ||
|
|
||
| model MemberChallengeAccess { | ||
|
There was a problem hiding this comment. Choose a reason for hiding this commentThe reason will be displayed to describe this comment to others. Learn more. [ |
||
| challengeId String | ||
| memberId String | ||
|
|
||
| challenge Challenge @relation(fields: [challengeId], references: [id]) | ||
|
|
||
| @@id([challengeId, memberId]) | ||
| @@map("MemberChallengeAccess") | ||
| } | ||
|
|
||
| ////////////////////////////////////////// | ||
| // ChallengeType model | ||
| ////////////////////////////////////////// | ||
|
|
||
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
[💡
design]The
fuzzystrmatchextension is being created in theskillsschema. Ensure that this schema is the intended location for this extension, as it might be more conventional to place extensions in thepublicorpg_catalogschemas unless there's a specific reason for this choice.