Skip to content

Commit 76f399d

Browse files
marc0derclaude
andcommitted
refactor: consolidate audit indexes into comprehensive migration with query documentation
Co-Authored-By: Claude <[email protected]>
1 parent fc9962f commit 76f399d

File tree

3 files changed

+147
-7
lines changed

3 files changed

+147
-7
lines changed

README.md

Lines changed: 115 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -52,4 +52,118 @@ http POST localhost:8080/versions \
5252
### GET versions for a candidate:
5353
```bash
5454
http GET localhost:8080/versions/java
55-
```
55+
```
56+
57+
## Audit Table Query Scenarios
58+
59+
The audit table tracks download and usage events for SDKMAN candidates. The following indexes optimize common analytical queries:
60+
61+
### Download Count for a Candidate (Last 30 Days)
62+
```sql
63+
SELECT COUNT(*) as downloads
64+
FROM audit
65+
WHERE candidate = 'java'
66+
AND timestamp > NOW() - INTERVAL '30 days';
67+
```
68+
*Uses index:* `idx_audit_candidate_timestamp`
69+
70+
### Top 10 Most Downloaded Versions (by Candidate)
71+
```sql
72+
SELECT version, COUNT(*) as downloads
73+
FROM audit
74+
WHERE candidate = 'gradle'
75+
GROUP BY version
76+
ORDER BY downloads DESC
77+
LIMIT 10;
78+
```
79+
*Uses index:* `idx_audit_candidate_version_timestamp`
80+
81+
### Download Trends by Version Over Time
82+
```sql
83+
SELECT version,
84+
DATE_TRUNC('week', timestamp) as week,
85+
COUNT(*) as downloads
86+
FROM audit
87+
WHERE candidate = 'kotlin'
88+
AND timestamp > NOW() - INTERVAL '6 months'
89+
GROUP BY version, week
90+
ORDER BY week DESC, downloads DESC;
91+
```
92+
*Uses index:* `idx_audit_candidate_version_timestamp`
93+
94+
### Command-Specific Analytics (Install vs Use)
95+
```sql
96+
SELECT command, COUNT(*) as count
97+
FROM audit
98+
WHERE candidate = 'java'
99+
AND timestamp > NOW() - INTERVAL '90 days'
100+
GROUP BY command
101+
ORDER BY count DESC;
102+
```
103+
*Uses index:* `idx_audit_candidate_command_timestamp`
104+
105+
### Recent Activity Across All Candidates
106+
```sql
107+
SELECT candidate,
108+
COUNT(*) as events,
109+
MAX(timestamp) as last_activity
110+
FROM audit
111+
WHERE timestamp > NOW() - INTERVAL '7 days'
112+
GROUP BY candidate
113+
ORDER BY events DESC;
114+
```
115+
*Uses index:* `idx_audit_timestamp_candidate`
116+
117+
### Platform Distribution for a Candidate
118+
```sql
119+
SELECT platform,
120+
COUNT(*) as downloads,
121+
ROUND(COUNT(*) * 100.0 / SUM(COUNT(*)) OVER (), 2) as percentage
122+
FROM audit
123+
WHERE candidate = 'kotlin'
124+
AND timestamp > NOW() - INTERVAL '90 days'
125+
GROUP BY platform
126+
ORDER BY downloads DESC;
127+
```
128+
*Uses index:* `idx_audit_candidate_platform_timestamp`
129+
130+
### Vendor Popularity Comparison by Platform (Java Distributions)
131+
```sql
132+
SELECT vendor,
133+
platform,
134+
COUNT(*) as downloads,
135+
COUNT(DISTINCT DATE_TRUNC('day', timestamp)) as days_active
136+
FROM audit
137+
WHERE candidate = 'java'
138+
AND platform = 'LINUX_X64'
139+
AND vendor IS NOT NULL
140+
AND timestamp > NOW() - INTERVAL '6 months'
141+
GROUP BY vendor, platform
142+
ORDER BY downloads DESC;
143+
```
144+
*Uses index:* `idx_audit_candidate_platform_vendor_timestamp`
145+
146+
### Most Active Users by Host (Top 20)
147+
```sql
148+
SELECT host,
149+
COUNT(*) as activity_count,
150+
COUNT(DISTINCT candidate) as unique_candidates,
151+
MAX(timestamp) as last_seen
152+
FROM audit
153+
WHERE timestamp > NOW() - INTERVAL '30 days'
154+
AND host IS NOT NULL
155+
GROUP BY host
156+
ORDER BY activity_count DESC
157+
LIMIT 20;
158+
```
159+
160+
### Peak Usage Times (Hourly Distribution)
161+
```sql
162+
SELECT EXTRACT(HOUR FROM timestamp) as hour,
163+
COUNT(*) as events
164+
FROM audit
165+
WHERE timestamp > NOW() - INTERVAL '7 days'
166+
GROUP BY hour
167+
ORDER BY hour;
168+
```
169+
*Uses index:* `idx_audit_timestamp_candidate`

src/main/resources/db/migration/V6__add_audit_index_candidate_timestamp.sql

Lines changed: 0 additions & 6 deletions
This file was deleted.
Lines changed: 32 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,32 @@
1+
-- flyway:no-transaction
2+
3+
-- Index for queries filtering by candidate with time-based ordering
4+
-- Use cases: download counts per candidate, recent activity for a candidate, time-series analysis
5+
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_audit_candidate_timestamp
6+
ON audit (candidate, timestamp DESC);
7+
8+
-- Index for queries filtering by candidate and version with time-based ordering
9+
-- Use cases: version-specific download counts, version adoption trends, most downloaded versions per candidate
10+
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_audit_candidate_version_timestamp
11+
ON audit (candidate, version, timestamp DESC);
12+
13+
-- Index for queries filtering by candidate and command type with time-based ordering
14+
-- Use cases: command-specific analytics (install vs use), event type filtering, command-specific trends
15+
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_audit_candidate_command_timestamp
16+
ON audit (candidate, command, timestamp DESC);
17+
18+
-- Index for queries filtering by time range with candidate grouping
19+
-- Use cases: recent activity across all candidates, time-based filtering with candidate aggregation, last 30 days analytics
20+
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_audit_timestamp_candidate
21+
ON audit (timestamp DESC, candidate);
22+
23+
-- Index for queries filtering by candidate and platform with time-based ordering
24+
-- Use cases: platform-specific download statistics, platform adoption trends, architecture/OS analysis
25+
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_audit_candidate_platform_timestamp
26+
ON audit (candidate, platform, timestamp DESC);
27+
28+
-- Partial index for queries filtering by vendor and platform (excludes NULL vendors for efficiency)
29+
-- Use cases: platform and vendor popularity analysis, Java distribution comparisons (Zulu vs Temurin) per platform, vendor-specific trends
30+
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_audit_candidate_platform_vendor_timestamp
31+
ON audit (candidate, platform, vendor, timestamp DESC)
32+
WHERE vendor IS NOT NULL;

0 commit comments

Comments
 (0)