From ce66caa17c94abcc4faf2527c983b2a7b1beb960 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Th=C3=A9ophile=20Choutri=20de=20Tarl=C3=A9?= Date: Sun, 6 Oct 2024 14:04:33 +0200 Subject: [PATCH] Add CI check for missing FK indexes (#605) --- .github/workflows/backend.yml | 11 +-- .github/workflows/check-missing-fk-indexes.sh | 13 +++ .github/workflows/missing-fk-indexes.yml | 97 +++++++++++++++++++ changelog.d/605 | 2 + environment.ci.sh | 3 +- .../20241004135653_missing_fk_indexes.sql | 8 ++ scripts/missing-fk-indexes.sql | 54 +++++++++++ 7 files changed, 180 insertions(+), 8 deletions(-) create mode 100755 .github/workflows/check-missing-fk-indexes.sh create mode 100644 .github/workflows/missing-fk-indexes.yml create mode 100644 changelog.d/605 create mode 100644 migrations/20241004135653_missing_fk_indexes.sql create mode 100644 scripts/missing-fk-indexes.sql diff --git a/.github/workflows/backend.yml b/.github/workflows/backend.yml index d049e93b..908fe0aa 100644 --- a/.github/workflows/backend.yml +++ b/.github/workflows/backend.yml @@ -16,14 +16,13 @@ jobs: outputs: matrix: ${{ steps.set-matrix.outputs.matrix }} steps: - - name: Checkout base repo - uses: actions/checkout@v4 - name: Extract the tested GHC versions id: set-matrix - run: | - wget https://github.com/Kleidukos/get-tested/releases/download/v0.1.4.0/get-tested-0.1.4.0-linux-amd64 -O get-tested - chmod +x get-tested - ./get-tested --ubuntu *.cabal >> $GITHUB_OUTPUT + uses: kleidukos/get-tested@v0.1.7.1 + with: + cabal-file: flora.cabal + ubuntu-version: "latest" + version: 0.1.7.1 Backend_tests: needs: generateMatrix diff --git a/.github/workflows/check-missing-fk-indexes.sh b/.github/workflows/check-missing-fk-indexes.sh new file mode 100755 index 00000000..2129762a --- /dev/null +++ b/.github/workflows/check-missing-fk-indexes.sh @@ -0,0 +1,13 @@ +#!/usr/bin/env bash + +set -euo pipefail + +output="$(psql "$FLORA_DB_CONNSTRING" -f scripts/missing-fk-indexes.sql 2>&1 > /dev/null)" + +if [[ "$output" == *"Missing FK indexes"* ]] +then + echo "Missing FK index! Run \`psql \"\$FLORA_DB_CONNSTRING\" -f scripts/missing-fk-indexes.sql\` and apply them" + exit 1 +else + exit 0 +fi diff --git a/.github/workflows/missing-fk-indexes.yml b/.github/workflows/missing-fk-indexes.yml new file mode 100644 index 00000000..e91b9a05 --- /dev/null +++ b/.github/workflows/missing-fk-indexes.yml @@ -0,0 +1,97 @@ +name: Missing FK Indexes + +on: + pull_request: + push: + branches: ["main", "development"] + +concurrency: + group: missing-kf-indexes-${{ github.ref_name }} + cancel-in-progress: true + +jobs: + generateMatrix: + name: "Generate matrix from cabal" + runs-on: ubuntu-latest + outputs: + matrix: ${{ steps.set-matrix.outputs.matrix }} + steps: + - name: Extract the tested GHC versions + id: set-matrix + uses: kleidukos/get-tested@v0.1.7.1 + with: + cabal-file: flora.cabal + ubuntu-version: "latest" + version: 0.1.7.1 + + index-check: + needs: generateMatrix + runs-on: ${{ matrix.os }} + strategy: + matrix: ${{ fromJSON(needs.generateMatrix.outputs.matrix) }} + # 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" + + - 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/cache@v4.0.2 + 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: Migrate + run: | + cabal install postgresql-migration + 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: | + source ./environment.ci.sh + .github/workflows/check-missing-fk-indexes.sh diff --git a/changelog.d/605 b/changelog.d/605 new file mode 100644 index 00000000..34564e00 --- /dev/null +++ b/changelog.d/605 @@ -0,0 +1,2 @@ +synopsis: Add CI check for missing FK indexes +prs: #605 diff --git a/environment.ci.sh b/environment.ci.sh index d98aa5f8..3ecff645 100755 --- a/environment.ci.sh +++ b/environment.ci.sh @@ -10,5 +10,4 @@ export FLORA_DB_USER="postgres" export FLORA_LOGGING_DESTINATION="stdout" export FLORA_HTTP_PORT=8083 -export FLORA_DB_CONNSTRING="host=${FLORA_DB_HOST} dbname=${FLORA_DB_DATABASE}\ - user=${FLORA_DB_USER} password=${FLORA_DB_PASSWORD}" +export FLORA_DB_CONNSTRING="host=${FLORA_DB_HOST} dbname=${FLORA_DB_DATABASE} user=${FLORA_DB_USER} password=${FLORA_DB_PASSWORD}" diff --git a/migrations/20241004135653_missing_fk_indexes.sql b/migrations/20241004135653_missing_fk_indexes.sql new file mode 100644 index 00000000..6ee0d5ee --- /dev/null +++ b/migrations/20241004135653_missing_fk_indexes.sql @@ -0,0 +1,8 @@ +CREATE INDEX user_organisation_organisation_id_fkey ON user_organisation(organisation_id); +CREATE INDEX user_organisation_user_id_fkey ON user_organisation(user_id); +CREATE INDEX packages_owner_id_fkey ON packages(owner_id); +CREATE INDEX package_publishers_package_id_fkey ON package_publishers(package_id); +CREATE INDEX package_publishers_user_id_fkey ON package_publishers(user_id); +CREATE INDEX repository ON releases(repository); +CREATE INDEX requirements_package_id_fkey ON requirements(package_id); +CREATE INDEX package_categories_category_id_fkey ON package_categories(category_id); diff --git a/scripts/missing-fk-indexes.sql b/scripts/missing-fk-indexes.sql new file mode 100644 index 00000000..519d1fc5 --- /dev/null +++ b/scripts/missing-fk-indexes.sql @@ -0,0 +1,54 @@ +-- ® Marc Cousin 2024 +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;