Skip to content

Commit

Permalink
Add CI check for missing FK indexes (#605)
Browse files Browse the repository at this point in the history
  • Loading branch information
tchoutri authored Oct 6, 2024
1 parent 29aa0d8 commit ce66caa
Show file tree
Hide file tree
Showing 7 changed files with 180 additions and 8 deletions.
11 changes: 5 additions & 6 deletions .github/workflows/backend.yml
Original file line number Diff line number Diff line change
Expand Up @@ -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/[email protected]
with:
cabal-file: flora.cabal
ubuntu-version: "latest"
version: 0.1.7.1

Backend_tests:
needs: generateMatrix
Expand Down
13 changes: 13 additions & 0 deletions .github/workflows/check-missing-fk-indexes.sh
Original file line number Diff line number Diff line change
@@ -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
97 changes: 97 additions & 0 deletions .github/workflows/missing-fk-indexes.yml
Original file line number Diff line number Diff line change
@@ -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/[email protected]
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/[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: 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
2 changes: 2 additions & 0 deletions changelog.d/605
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
synopsis: Add CI check for missing FK indexes
prs: #605
3 changes: 1 addition & 2 deletions environment.ci.sh
Original file line number Diff line number Diff line change
Expand Up @@ -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}"
8 changes: 8 additions & 0 deletions migrations/20241004135653_missing_fk_indexes.sql
Original file line number Diff line number Diff line change
@@ -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);
54 changes: 54 additions & 0 deletions scripts/missing-fk-indexes.sql
Original file line number Diff line number Diff line change
@@ -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;

0 comments on commit ce66caa

Please sign in to comment.