Skip to content

Commit ce66caa

Browse files
authored
Add CI check for missing FK indexes (#605)
1 parent 29aa0d8 commit ce66caa

7 files changed

+180
-8
lines changed

.github/workflows/backend.yml

+5-6
Original file line numberDiff line numberDiff line change
@@ -16,14 +16,13 @@ jobs:
1616
outputs:
1717
matrix: ${{ steps.set-matrix.outputs.matrix }}
1818
steps:
19-
- name: Checkout base repo
20-
uses: actions/checkout@v4
2119
- name: Extract the tested GHC versions
2220
id: set-matrix
23-
run: |
24-
wget https://github.com/Kleidukos/get-tested/releases/download/v0.1.4.0/get-tested-0.1.4.0-linux-amd64 -O get-tested
25-
chmod +x get-tested
26-
./get-tested --ubuntu *.cabal >> $GITHUB_OUTPUT
21+
uses: kleidukos/[email protected]
22+
with:
23+
cabal-file: flora.cabal
24+
ubuntu-version: "latest"
25+
version: 0.1.7.1
2726

2827
Backend_tests:
2928
needs: generateMatrix
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,13 @@
1+
#!/usr/bin/env bash
2+
3+
set -euo pipefail
4+
5+
output="$(psql "$FLORA_DB_CONNSTRING" -f scripts/missing-fk-indexes.sql 2>&1 > /dev/null)"
6+
7+
if [[ "$output" == *"Missing FK indexes"* ]]
8+
then
9+
echo "Missing FK index! Run \`psql \"\$FLORA_DB_CONNSTRING\" -f scripts/missing-fk-indexes.sql\` and apply them"
10+
exit 1
11+
else
12+
exit 0
13+
fi
+97
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,97 @@
1+
name: Missing FK Indexes
2+
3+
on:
4+
pull_request:
5+
push:
6+
branches: ["main", "development"]
7+
8+
concurrency:
9+
group: missing-kf-indexes-${{ github.ref_name }}
10+
cancel-in-progress: true
11+
12+
jobs:
13+
generateMatrix:
14+
name: "Generate matrix from cabal"
15+
runs-on: ubuntu-latest
16+
outputs:
17+
matrix: ${{ steps.set-matrix.outputs.matrix }}
18+
steps:
19+
- name: Extract the tested GHC versions
20+
id: set-matrix
21+
uses: kleidukos/[email protected]
22+
with:
23+
cabal-file: flora.cabal
24+
ubuntu-version: "latest"
25+
version: 0.1.7.1
26+
27+
index-check:
28+
needs: generateMatrix
29+
runs-on: ${{ matrix.os }}
30+
strategy:
31+
matrix: ${{ fromJSON(needs.generateMatrix.outputs.matrix) }}
32+
# Service containers to run with `container-job`
33+
services:
34+
# Label used to access the service container
35+
postgres:
36+
# Docker Hub image
37+
image: postgres
38+
# Provide the password for postgres
39+
env:
40+
POSTGRES_PASSWORD: postgres
41+
# Set health checks to wait until postgres has started
42+
options: >-
43+
--health-cmd pg_isready
44+
--health-interval 10s
45+
--health-timeout 5s
46+
--health-retries 5
47+
ports:
48+
- 5432:5432
49+
steps:
50+
- uses: actions/checkout@v4
51+
52+
- name: Set up Haskell
53+
id: setup-haskell
54+
uses: haskell-actions/setup@v2
55+
with:
56+
ghc-version: "${{ matrix.ghc }}"
57+
cabal-version: "latest"
58+
59+
- name: Configure environment
60+
run: |
61+
./.github/workflows/setup.sh
62+
echo "/usr/lib/postgresql/14/bin/" >> $GITHUB_PATH
63+
echo "$HOME/.ghcup/bin" >> $GITHUB_PATH
64+
echo "$HOME/.cabal/bin" >> $GITHUB_PATH
65+
echo "$HOME/.local/bin" >> $GITHUB_PATH
66+
echo "$HOME/node_modules/.bin" >> $GITHUB_PATH
67+
sudo apt install libsodium-dev
68+
source ./environment.ci.sh
69+
touch ~/.pgpass
70+
chmod 0600 ~/.pgpass
71+
echo "${FLORA_DB_HOST}:${FLORA_DB_PORT}:${FLORA_DB_DATABASE}:${FLORA_DB_USER}:${FLORA_DB_PASSWORD}" > .pgpass
72+
cat ~/.pgpass
73+
cabal update
74+
75+
- name: Cache
76+
uses: actions/[email protected]
77+
with:
78+
path: ${{ steps.setup-haskell.outputs.cabal-store }}
79+
key: ${{ runner.os }}-ghc-${{ matrix.ghc }}-cabal-${{ hashFiles('./.plan.json') }}
80+
restore-keys: ${{ runner.os }}-ghc-${{ matrix.ghc }}-
81+
82+
83+
- name: Migrate
84+
run: |
85+
cabal install postgresql-migration
86+
set -x
87+
source ./environment.ci.sh
88+
createdb -h "${FLORA_DB_HOST}" -p "${FLORA_DB_PORT}" -U "${FLORA_DB_USER}" -w "${FLORA_DB_DATABASE}"
89+
migrate init "${FLORA_DB_CONNSTRING}"
90+
migrate migrate "${FLORA_DB_CONNSTRING}" migrations
91+
env:
92+
PGPASSWORD: "postgres"
93+
94+
- name: Check
95+
run: |
96+
source ./environment.ci.sh
97+
.github/workflows/check-missing-fk-indexes.sh

changelog.d/605

+2
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
synopsis: Add CI check for missing FK indexes
2+
prs: #605

environment.ci.sh

+1-2
Original file line numberDiff line numberDiff line change
@@ -10,5 +10,4 @@ export FLORA_DB_USER="postgres"
1010
export FLORA_LOGGING_DESTINATION="stdout"
1111
export FLORA_HTTP_PORT=8083
1212

13-
export FLORA_DB_CONNSTRING="host=${FLORA_DB_HOST} dbname=${FLORA_DB_DATABASE}\
14-
user=${FLORA_DB_USER} password=${FLORA_DB_PASSWORD}"
13+
export FLORA_DB_CONNSTRING="host=${FLORA_DB_HOST} dbname=${FLORA_DB_DATABASE} user=${FLORA_DB_USER} password=${FLORA_DB_PASSWORD}"
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
CREATE INDEX user_organisation_organisation_id_fkey ON user_organisation(organisation_id);
2+
CREATE INDEX user_organisation_user_id_fkey ON user_organisation(user_id);
3+
CREATE INDEX packages_owner_id_fkey ON packages(owner_id);
4+
CREATE INDEX package_publishers_package_id_fkey ON package_publishers(package_id);
5+
CREATE INDEX package_publishers_user_id_fkey ON package_publishers(user_id);
6+
CREATE INDEX repository ON releases(repository);
7+
CREATE INDEX requirements_package_id_fkey ON requirements(package_id);
8+
CREATE INDEX package_categories_category_id_fkey ON package_categories(category_id);

scripts/missing-fk-indexes.sql

+54
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,54 @@
1+
-- ® Marc Cousin 2024
2+
DO
3+
$$
4+
DECLARE
5+
numversion int;
6+
indkeysfilter varchar;
7+
indexquery varchar;
8+
missing_indexes varchar;
9+
BEGIN
10+
SELECT INTO numversion setting FROM pg_settings WHERE name = 'server_version_num';
11+
-- manage covering indexes in PG 11
12+
IF numversion >= 110000 THEN
13+
RAISE DEBUG 'numversion %',numversion;
14+
indkeysfilter := '((indkey::int4[])[0:indnkeyatts-1])[1:array_upper(conkey,1)]';
15+
ELSE
16+
indkeysfilter := '((indkey::int4[]))[0:array_upper(conkey,1) - 1]';
17+
END IF;
18+
19+
20+
indexquery := format('
21+
with not_indexed_constraints as (
22+
select conname, conrelid::regclass as tablename, conkey
23+
from pg_constraint
24+
where contype = ''f''
25+
and not exists (
26+
select 1
27+
from pg_index
28+
where indrelid=conrelid
29+
and %s @> conkey::int4[]
30+
and %s <@ conkey::int4[]
31+
and indpred is null
32+
)
33+
and not exists (
34+
select 1 from pg_depend
35+
where objid = conrelid and classid = ''pg_class''::regclass and deptype = ''e''
36+
)
37+
),
38+
unnested_constraints as (
39+
select conname, tablename, unnest.* FROM not_indexed_constraints,unnest(conkey) with ordinality),
40+
missing_indexes as (
41+
SELECT ''CREATE INDEX CONCURRENTLY '' || conname || '' ON '' || tablename::text || ''('' ||
42+
string_agg(quote_ident(attname::text), '','' order by ordinality) || '');'' as indexes
43+
from unnested_constraints
44+
join pg_attribute on (unnested_constraints.tablename=pg_attribute.attrelid
45+
and pg_attribute.attnum=unnested_constraints.unnest)
46+
group by tablename,conname)
47+
SELECT string_agg(indexes,E''\n'') as indexes from missing_indexes', indkeysfilter, indkeysfilter);
48+
49+
EXECUTE indexquery INTO missing_indexes;
50+
IF length(missing_indexes) > 0 THEN
51+
RAISE 'Missing FK indexes: %',missing_indexes;
52+
END IF;
53+
END;
54+
$$ LANGUAGE plpgsql;

0 commit comments

Comments
 (0)