-
-
Notifications
You must be signed in to change notification settings - Fork 41
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
5 changed files
with
187 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,11 @@ | ||
#!/usr/bin/env bash | ||
|
||
output=$(psql $FLORA_DB_CONNSTRING < scripts/missing-fk-indexes.sql) | ||
|
||
if [[ $output == *"Missing FK indexes"* ]] | ||
then | ||
print "Missing FK index! Run \`psql \$FLORA_DB_CONNSTRING < scripts/missing-fk-indexes.sql\` and apply them" | ||
exit 1 | ||
else | ||
exit 0 | ||
fi |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,91 @@ | ||
name: Missing FK Indexes | ||
|
||
on: | ||
pull_request: | ||
push: | ||
branches: ["main", "development"] | ||
|
||
concurrency: | ||
group: backend-${{ github.ref_name }} | ||
cancel-in-progress: true | ||
|
||
jobs: | ||
index-check: | ||
runs-on: ubuntu-latest | ||
# Service containers to run with `container-job` | ||
services: | ||
# Label used to access the service container | ||
postgres: | ||
# Docker Hub image | ||
image: postgres | ||
# Provide the password for postgres | ||
env: | ||
POSTGRES_PASSWORD: postgres | ||
# Set health checks to wait until postgres has started | ||
options: >- | ||
--health-cmd pg_isready | ||
--health-interval 10s | ||
--health-timeout 5s | ||
--health-retries 5 | ||
ports: | ||
- 5432:5432 | ||
steps: | ||
- uses: actions/checkout@v4 | ||
|
||
- name: Set up Haskell | ||
id: setup-haskell | ||
uses: haskell-actions/setup@v2 | ||
with: | ||
ghc-version: "${{ matrix.ghc }}" | ||
cabal-version: "latest" | ||
|
||
- uses: actions/setup-node@v4 | ||
with: | ||
node-version: "18" | ||
cache: "yarn" | ||
cache-dependency-path: assets/yarn.lock | ||
|
||
- name: Configure environment | ||
run: | | ||
./.github/workflows/setup.sh | ||
echo "/usr/lib/postgresql/14/bin/" >> $GITHUB_PATH | ||
echo "$HOME/.ghcup/bin" >> $GITHUB_PATH | ||
echo "$HOME/.cabal/bin" >> $GITHUB_PATH | ||
echo "$HOME/.local/bin" >> $GITHUB_PATH | ||
echo "$HOME/node_modules/.bin" >> $GITHUB_PATH | ||
sudo apt install libsodium-dev | ||
source ./environment.ci.sh | ||
touch ~/.pgpass | ||
chmod 0600 ~/.pgpass | ||
echo "${FLORA_DB_HOST}:${FLORA_DB_PORT}:${FLORA_DB_DATABASE}:${FLORA_DB_USER}:${FLORA_DB_PASSWORD}" > .pgpass | ||
cat ~/.pgpass | ||
cabal update | ||
- name: Cache | ||
uses: actions/[email protected] | ||
with: | ||
path: ${{ steps.setup-haskell.outputs.cabal-store }} | ||
key: ${{ runner.os }}-ghc-${{ matrix.ghc }}-cabal-${{ hashFiles('./.plan.json') }} | ||
restore-keys: ${{ runner.os }}-ghc-${{ matrix.ghc }}- | ||
|
||
- name: Build | ||
run: | | ||
cabal install postgresql-migration | ||
make soufflé | ||
make assets-deps | ||
make build-assets | ||
make build | ||
- name: Migrate | ||
run: | | ||
set -x | ||
source ./environment.ci.sh | ||
createdb -h "${FLORA_DB_HOST}" -p "${FLORA_DB_PORT}" -U "${FLORA_DB_USER}" -w "${FLORA_DB_DATABASE}" | ||
migrate init "${FLORA_DB_CONNSTRING}" | ||
migrate migrate "${FLORA_DB_CONNSTRING}" migrations | ||
env: | ||
PGPASSWORD: "postgres" | ||
|
||
- name: Check | ||
run: | | ||
.github/workflows/check-missing-fk-indexes.sh |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,8 @@ | ||
CREATE INDEX CONCURRENTLY user_organisation_organisation_id_fkey ON user_organisation(organisation_id); | ||
CREATE INDEX CONCURRENTLY user_organisation_user_id_fkey ON user_organisation(user_id); | ||
CREATE INDEX CONCURRENTLY packages_owner_id_fkey ON packages(owner_id); | ||
CREATE INDEX CONCURRENTLY package_publishers_package_id_fkey ON package_publishers(package_id); | ||
CREATE INDEX CONCURRENTLY package_publishers_user_id_fkey ON package_publishers(user_id); | ||
CREATE INDEX CONCURRENTLY repository ON releases(repository); | ||
CREATE INDEX CONCURRENTLY requirements_package_id_fkey ON requirements(package_id); | ||
CREATE INDEX CONCURRENTLY package_categories_category_id_fkey ON package_categories(category_id); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,24 @@ | ||
-- Amelioré, détecte unique et index partiels | ||
with indexdata as (SELECT *, | ||
array_to_string(indkey,'+') AS colindex, | ||
lag(array_to_string(indkey,'+')) OVER search_window AS colprecedingindex, | ||
lag(indexrelid) OVER search_window AS preceding_index, | ||
lag(indisunique) OVER search_window AS preceding_indisunique, | ||
lag(indpred) OVER search_window AS predeciding_indpred | ||
|
||
FROM pg_index | ||
WINDOW search_window AS (PARTITION BY indrelid | ||
ORDER BY array_to_string(indkey,'+') DESC) | ||
), | ||
indexdef AS ( | ||
SELECT *, | ||
pg_get_indexdef(indexrelid) as contained, | ||
pg_get_indexdef(preceding_index) as contains | ||
FROM indexdata | ||
) | ||
|
||
SELECT contained,contains FROM indexdef | ||
WHERE colprecedingindex LIKE (colindex || '+%') | ||
AND ((indisunique and preceding_indisunique) OR (not indisunique and not preceding_indisunique)) | ||
AND (indpred = predeciding_indpred) | ||
; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,53 @@ | ||
DO | ||
$$ | ||
DECLARE | ||
numversion int; | ||
indkeysfilter varchar; | ||
indexquery varchar; | ||
missing_indexes varchar; | ||
BEGIN | ||
SELECT INTO numversion setting FROM pg_settings WHERE name = 'server_version_num'; | ||
-- manage covering indexes in PG 11 | ||
IF numversion >= 110000 THEN | ||
RAISE DEBUG 'numversion %',numversion; | ||
indkeysfilter := '((indkey::int4[])[0:indnkeyatts-1])[1:array_upper(conkey,1)]'; | ||
ELSE | ||
indkeysfilter := '((indkey::int4[]))[0:array_upper(conkey,1) - 1]'; | ||
END IF; | ||
|
||
|
||
indexquery := format(' | ||
with not_indexed_constraints as ( | ||
select conname, conrelid::regclass as tablename, conkey | ||
from pg_constraint | ||
where contype = ''f'' | ||
and not exists ( | ||
select 1 | ||
from pg_index | ||
where indrelid=conrelid | ||
and %s @> conkey::int4[] | ||
and %s <@ conkey::int4[] | ||
and indpred is null | ||
) | ||
and not exists ( | ||
select 1 from pg_depend | ||
where objid = conrelid and classid = ''pg_class''::regclass and deptype = ''e'' | ||
) | ||
), | ||
unnested_constraints as ( | ||
select conname, tablename, unnest.* FROM not_indexed_constraints,unnest(conkey) with ordinality), | ||
missing_indexes as ( | ||
SELECT ''CREATE INDEX CONCURRENTLY '' || conname || '' ON '' || tablename::text || ''('' || | ||
string_agg(quote_ident(attname::text), '','' order by ordinality) || '');'' as indexes | ||
from unnested_constraints | ||
join pg_attribute on (unnested_constraints.tablename=pg_attribute.attrelid | ||
and pg_attribute.attnum=unnested_constraints.unnest) | ||
group by tablename,conname) | ||
SELECT string_agg(indexes,E''\n'') as indexes from missing_indexes', indkeysfilter, indkeysfilter); | ||
|
||
EXECUTE indexquery INTO missing_indexes; | ||
IF length(missing_indexes) > 0 THEN | ||
RAISE 'Missing FK indexes: %',missing_indexes; | ||
END IF; | ||
END; | ||
$$ LANGUAGE plpgsql; |