Skip to content
GitLab
Explore
Sign in
Primary navigation
Search or go to…
Project
bobgroup-go-utils
Manage
Activity
Members
Labels
Plan
Issues
Issue boards
Milestones
Wiki
Code
Merge requests
Repository
Branches
Commits
Tags
Repository graph
Compare revisions
Snippets
Build
Pipelines
Jobs
Pipeline schedules
Artifacts
Deploy
Releases
Package registry
Container Registry
Model registry
Operate
Environments
Terraform modules
Monitor
Incidents
Analyze
Value stream analytics
Contributor analytics
CI/CD analytics
Repository analytics
Model experiments
Help
Help
Support
GitLab documentation
Compare GitLab plans
Community forum
Contribute to GitLab
Provide feedback
Keyboard shortcuts
?
Snippets
Groups
Projects
Show more breadcrumbs
Bob Public Utils
bobgroup-go-utils
Commits
6c641657
Commit
6c641657
authored
3 months ago
by
James Page
Browse files
Options
Downloads
Patches
Plain Diff
#43
- Index checks for crons
parent
413c354e
No related branches found
Branches containing commit
No related tags found
Tags containing commit
1 merge request
!58
Resolve "Create index-checks package"
Changes
2
Hide whitespace changes
Inline
Side-by-side
Showing
2 changed files
db_utils/db_queries.go
+223
-0
223 additions, 0 deletions
db_utils/db_queries.go
db_utils/db_utils.go
+74
-0
74 additions, 0 deletions
db_utils/db_utils.go
with
297 additions
and
0 deletions
db_utils/db_queries.go
0 → 100644
+
223
−
0
View file @
6c641657
package
db_utils
const
TableIndexStatusQuery
=
`
SELECT
relname AS table_name,
CASE WHEN seq_scan + idx_scan = 0 THEN 0
ELSE 100 * idx_scan / (seq_scan + idx_scan)
END AS percent_usage,
n_live_tup AS rows_in_table,
CASE
-- List tables without rows separately.
WHEN n_live_tup = 0 THEN ?
-- Problem indices.
WHEN seq_scan + idx_scan = 0 AND n_live_tup > 0 THEN ?
WHEN 100 * idx_scan / (seq_scan + idx_scan) < 98 THEN ?
-- Everything else is considered healthy.
ELSE ?
END
AS status
FROM
pg_stat_user_tables
ORDER BY
n_live_tup DESC;
`
const
ProblemIndexQuery
=
`
WITH table_scans AS (
SELECT
relid,
tables.idx_scan + tables.seq_scan AS all_scans,
(
tables.n_tup_ins + tables.n_tup_upd + tables.n_tup_del
) AS writes,
pg_relation_size(relid) AS table_size
FROM
pg_stat_user_tables AS TABLES
),
all_writes AS (
SELECT
sum(writes) AS total_writes
FROM
table_scans
),
indexes AS (
SELECT
idx_stat.relid,
idx_stat.indexrelid,
idx_stat.schemaname AS schema_name,
idx_stat.relname AS table_name,
idx_stat.indexrelname AS index_name,
idx_stat.idx_scan,
pg_relation_size(idx_stat.indexrelid) AS index_bytes,
indexdef ~* 'USING btree' AS idx_is_btree
FROM
pg_stat_user_indexes AS idx_stat
JOIN pg_index
USING (indexrelid)
JOIN pg_indexes AS INDEXES
ON
idx_stat.schemaname = indexes.schemaname
AND idx_stat.relname = indexes.tablename
AND idx_stat.indexrelname = indexes.indexname
WHERE
pg_index.indisunique = FALSE
),
index_ratios AS (
SELECT
schema_name,
table_name,
index_name,
idx_scan,
all_scans,
round(
(
CASE
WHEN all_scans = 0 THEN 0.0::NUMERIC
ELSE idx_scan::NUMERIC / all_scans * 100
END
),
2
) AS index_scan_percentage,
writes,
round(
(
CASE
WHEN writes = 0 THEN idx_scan::NUMERIC
ELSE idx_scan::NUMERIC / writes
END
),
2
)
AS scans_per_write,
pg_size_pretty(index_bytes) AS index_size,
pg_size_pretty(table_size) AS table_size,
idx_is_btree,
index_bytes
FROM
INDEXES
JOIN table_scans
USING (relid)
),
index_groups AS (
SELECT
-- Never-used indexes
? AS reason,
*,
1 AS grp
FROM
index_ratios
WHERE
idx_scan = 0
AND idx_is_btree
UNION ALL
SELECT
-- Low scans, high writes
? AS reason,
*,
2 AS grp
FROM
index_ratios
WHERE
scans_per_write <= 1
AND index_scan_percentage < 10
AND idx_scan > 0
AND writes > 100
AND idx_is_btree
UNION ALL
SELECT
-- Seldom Used Large Indexes
? AS reason,
*,
3 AS grp
FROM
index_ratios
WHERE
index_scan_percentage < 5
AND scans_per_write > 1
AND idx_scan > 0
AND idx_is_btree
AND index_bytes > 100000000
UNION ALL
SELECT
-- High-Write Large Non-Btree
? AS reason,
index_ratios.*,
4 AS grp
FROM
index_ratios,
all_writes
WHERE
(
writes::NUMERIC / (
total_writes + 1
)
) > 0.02
AND NOT idx_is_btree
AND index_bytes > 100000000
ORDER BY
grp,
index_bytes DESC
)
SELECT
reason,
schema_name,
table_name,
index_name,
index_scan_percentage,
scans_per_write,
index_size,
table_size
FROM
index_groups
;
`
const
ExistingIndexQuery
=
`
SELECT
c.relname AS index_name,
c.relpages AS index_size
FROM
pg_index i
JOIN pg_opclass op ON
i.indclass[0] = op.oid
JOIN pg_am am ON
op.opcmethod = am.oid
JOIN pg_class c ON
i.indexrelid = c.oid
JOIN pg_namespace n ON
c.relnamespace = n.oid
WHERE
am.amname = 'btree'
AND n.nspname = 'public'
-- Don't check temp tables, which may be from another session:
AND c.relpersistence != 't'
-- Function may throw an error when this is omitted:
AND c.relkind = 'i'
AND i.indisready
AND i.indisvalid
ORDER BY
c.relpages DESC
;
`
const
CorruptIndexQuery
=
`SELECT
bt_index_check(index => c.oid, heapallindexed => i.indisunique) AS check_result,
c.relname AS relation_name,
c.relpages AS relation_size
FROM pg_index i
JOIN pg_opclass op ON i.indclass[0] = op.oid
JOIN pg_am am ON op.opcmethod = am.oid
JOIN pg_class c ON i.indexrelid = c.oid
JOIN pg_namespace n ON c.relnamespace = n.oid
-- Only btree indices are currently supported by the index-checking function.
WHERE am.amname = 'btree'
-- We only analyse our own indices.
AND n.nspname = 'public'
AND relname IN (?)
-- Don't check temp tables, which may be from another session.
AND c.relpersistence != 't'
-- Function may throw an error when this is omitted.
AND c.relkind = 'i' AND i.indisready AND i.indisvalid
ORDER BY c.relpages DESC
;`
This diff is collapsed.
Click to expand it.
db_utils/db_utils.go
+
74
−
0
View file @
6c641657
...
@@ -11,6 +11,58 @@ import (
...
@@ -11,6 +11,58 @@ import (
"time"
"time"
)
)
const
(
TableIndexScanPercentageCheckHealthy
=
"healthy"
TableIndexScanPercentageCheckProblem
=
"problem"
TableIndexScanPercentageCheckEmptyTable
=
"empty_table"
)
const
(
IndexProblemReasonNeverUsedIndex
=
"Never-used index"
IndexProblemReasonLowScanHighWrite
=
"Low scan, high write"
IndexProblemReasonSeldomUsedLargeIndex
=
"Seldom-used large index"
IndexProblemReasonHighWriteLargeNonBTreeIndex
=
"High write, large non-BTree index"
)
type
Index
struct
{
IndexName
string
`json:"index_name"`
TableName
string
`json:"table_name"`
}
type
CorruptIndex
struct
{
CheckResult
string
`json:"check_result"`
// If there are no errors, this should be empty.
RelationName
string
`json:"relation_name"`
RelationSize
int64
`json:"relation_size"`
// This size in measured in pages.
}
type
LowIndexScanTable
struct
{
TableName
string
`json:"table_name"`
Status
string
`json:"index_name"`
PercentUsage
int64
`json:"percent_usage"`
RowsInTable
int64
`json:"rows_in_table"`
}
type
ProblemIndex
struct
{
TableName
string
`json:"table_name"`
IndexName
string
`json:"index_name"`
Reason
string
`json:"reason"`
IndexScanPercentage
float64
`json:"index_scan_percentage"`
IndexSize
string
`json:"index_size"`
TableSize
string
`json:"table_size"`
}
type
IndexHealthIssues
struct
{
CorruptIndexes
[]
CorruptIndex
`json:"corrupt_indexes"`
LowIndexScanTables
[]
LowIndexScanTable
`json:"low_index_scan_tables"`
ProblemIndexes
[]
ProblemIndex
`json:"problem_indexes"`
}
type
IndexError
struct
{
TableName
string
`json:"table_name"`
IndexName
string
`json:"index_name"`
Reason
string
`json:"reason"`
}
// Special query cases
// Special query cases
const
(
const
(
LastXHours
string
=
"^last
\\
d+ hour(s)?$"
LastXHours
string
=
"^last
\\
d+ hour(s)?$"
...
@@ -116,3 +168,25 @@ func ValidateDateFilters(params any, dateFiltersToValidate ...string) error {
...
@@ -116,3 +168,25 @@ func ValidateDateFilters(params any, dateFiltersToValidate ...string) error {
}
}
return
nil
return
nil
}
}
func
FindCommonNeverUsedIndexes
(
list1
,
list2
[]
ProblemIndex
)
[]
ProblemIndex
{
// Create a map to store indexes from the first list
indexMap
:=
make
(
map
[
string
]
ProblemIndex
)
for
_
,
index
:=
range
list1
{
if
index
.
Reason
==
IndexProblemReasonNeverUsedIndex
{
indexMap
[
index
.
IndexName
]
=
index
}
}
// Iterate through the second list and find common indexes
var
commonIndexes
[]
ProblemIndex
for
_
,
index
:=
range
list2
{
if
index
.
Reason
==
IndexProblemReasonNeverUsedIndex
{
if
_
,
exists
:=
indexMap
[
index
.
IndexName
];
exists
{
commonIndexes
=
append
(
commonIndexes
,
index
)
}
}
}
return
commonIndexes
}
This diff is collapsed.
Click to expand it.
Preview
0%
Loading
Try again
or
attach a new file
.
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Save comment
Cancel
Please
register
or
sign in
to comment