mirror of
https://github.com/pacnpal/thrilltrack-explorer.git
synced 2025-12-25 02:11:12 -05:00
feat: Complete versioning system transformation
This commit is contained in:
@@ -44,3 +44,88 @@ await supabase.rpc('set_session_variable', {
|
|||||||
value: auth.uid(), // Moderator who approved
|
value: auth.uid(), // Moderator who approved
|
||||||
});
|
});
|
||||||
```
|
```
|
||||||
|
|
||||||
|
## Automated Cleanup
|
||||||
|
|
||||||
|
### pg_cron Schedule
|
||||||
|
|
||||||
|
The versioning system automatically cleans up old versions monthly via `pg_cron`:
|
||||||
|
|
||||||
|
- **Schedule:** 2 AM UTC on the 1st of each month
|
||||||
|
- **Retention:** 50 most recent versions per entity (configurable)
|
||||||
|
- **Tables affected:** All `*_versions` tables (`park_versions`, `ride_versions`, `company_versions`, `ride_model_versions`)
|
||||||
|
|
||||||
|
### Manual Cleanup
|
||||||
|
|
||||||
|
To run cleanup manually for a specific entity type:
|
||||||
|
|
||||||
|
```sql
|
||||||
|
-- Clean up old park versions, keeping 50 most recent per park
|
||||||
|
SELECT cleanup_old_versions('park', 50);
|
||||||
|
|
||||||
|
-- Clean up rides, keeping 100 versions
|
||||||
|
SELECT cleanup_old_versions('ride', 100);
|
||||||
|
```
|
||||||
|
|
||||||
|
Or use the TypeScript utility:
|
||||||
|
|
||||||
|
```typescript
|
||||||
|
import { cleanupVersions } from '@/lib/versioningUtils';
|
||||||
|
|
||||||
|
// Clean up old park versions
|
||||||
|
const deletedCount = await cleanupVersions('park', 50);
|
||||||
|
console.log(`Deleted ${deletedCount} old versions`);
|
||||||
|
```
|
||||||
|
|
||||||
|
### Monitoring Cleanup Jobs
|
||||||
|
|
||||||
|
Check pg_cron job status:
|
||||||
|
|
||||||
|
```sql
|
||||||
|
-- View all cleanup jobs
|
||||||
|
SELECT * FROM cron.job WHERE jobname LIKE 'cleanup%';
|
||||||
|
|
||||||
|
-- View recent job execution history
|
||||||
|
SELECT * FROM cron.job_run_details
|
||||||
|
WHERE jobname LIKE 'cleanup%'
|
||||||
|
ORDER BY start_time DESC
|
||||||
|
LIMIT 10;
|
||||||
|
```
|
||||||
|
|
||||||
|
### Adjusting Retention Policy
|
||||||
|
|
||||||
|
To keep more or fewer versions, update the cron schedule:
|
||||||
|
|
||||||
|
```sql
|
||||||
|
-- Unschedule existing job
|
||||||
|
SELECT cron.unschedule('cleanup-park-versions');
|
||||||
|
|
||||||
|
-- Reschedule with new retention count
|
||||||
|
SELECT cron.schedule(
|
||||||
|
'cleanup-park-versions',
|
||||||
|
'0 2 1 * *', -- 2 AM UTC on 1st of month
|
||||||
|
$$SELECT cleanup_old_versions('park', 100);$$ -- Keep 100 versions
|
||||||
|
);
|
||||||
|
```
|
||||||
|
|
||||||
|
### Version Storage Monitoring
|
||||||
|
|
||||||
|
Monitor version table sizes:
|
||||||
|
|
||||||
|
```sql
|
||||||
|
-- Count versions per entity type
|
||||||
|
SELECT 'parks' as entity_type, COUNT(*) as total_versions
|
||||||
|
FROM park_versions
|
||||||
|
UNION ALL
|
||||||
|
SELECT 'rides', COUNT(*) FROM ride_versions
|
||||||
|
UNION ALL
|
||||||
|
SELECT 'companies', COUNT(*) FROM company_versions
|
||||||
|
UNION ALL
|
||||||
|
SELECT 'ride_models', COUNT(*) FROM ride_model_versions;
|
||||||
|
|
||||||
|
-- Get oldest version date per entity type
|
||||||
|
SELECT 'parks' as entity_type, MIN(created_at) as oldest_version
|
||||||
|
FROM park_versions
|
||||||
|
UNION ALL
|
||||||
|
SELECT 'rides', MIN(created_at) FROM ride_versions;
|
||||||
|
```
|
||||||
|
|||||||
@@ -33,8 +33,64 @@ The new system uses dedicated relational tables:
|
|||||||
|
|
||||||
- ✅ All new versions written to relational tables
|
- ✅ All new versions written to relational tables
|
||||||
- ✅ Triggers active on all entity tables
|
- ✅ Triggers active on all entity tables
|
||||||
|
- ✅ Automated cleanup scheduled via pg_cron
|
||||||
- ⚠️ Old `entity_versions` table retained for backward compatibility
|
- ⚠️ Old `entity_versions` table retained for backward compatibility
|
||||||
- ⚠️ `src/lib/versioningHelpers.ts` deprecated but not removed
|
- ⚠️ `src/lib/versioningHelpers.ts` deprecated but not removed (scheduled for removal: 2025-12-01)
|
||||||
|
|
||||||
|
## Migration Timeline
|
||||||
|
|
||||||
|
### ✅ Phase 1: New System Deployed (Completed)
|
||||||
|
- Relational version tables created (`park_versions`, `ride_versions`, etc.)
|
||||||
|
- Triggers enabled on all entity tables
|
||||||
|
- RLS policies active and tested
|
||||||
|
- Frontend integrated with new hooks
|
||||||
|
- Complete documentation suite created
|
||||||
|
|
||||||
|
### 🟡 Phase 2: Parallel Operation (Current - Days 1-30)
|
||||||
|
- Both old and new systems exist side-by-side
|
||||||
|
- New triggers create versions in relational tables
|
||||||
|
- Old JSONB table receives no new data
|
||||||
|
- Monitoring for issues and edge cases
|
||||||
|
- `versioningHelpers.ts` marked as deprecated
|
||||||
|
|
||||||
|
**Action Items:**
|
||||||
|
- [ ] Monitor version creation in new tables
|
||||||
|
- [ ] Verify no new inserts to old `entity_versions` table
|
||||||
|
- [ ] Search codebase for deprecated function usage
|
||||||
|
- [ ] Collect feedback from team
|
||||||
|
|
||||||
|
### 🔵 Phase 3: Archive Legacy Data (Day 30)
|
||||||
|
- Archive old `entity_versions` to `entity_versions_archive`
|
||||||
|
- Verify data integrity and counts match
|
||||||
|
- Keep archive for 60 more days as safety net
|
||||||
|
- Document archive location and access procedures
|
||||||
|
|
||||||
|
**SQL Migration:**
|
||||||
|
```sql
|
||||||
|
-- See supabase/migrations/*_archive_legacy_versions.sql
|
||||||
|
CREATE TABLE entity_versions_archive (LIKE entity_versions INCLUDING ALL);
|
||||||
|
INSERT INTO entity_versions_archive SELECT * FROM entity_versions;
|
||||||
|
```
|
||||||
|
|
||||||
|
### 🟢 Phase 4: Drop Legacy Tables (Day 90)
|
||||||
|
- Drop old `entity_versions` table
|
||||||
|
- Drop old RPC functions (`create_entity_version`, `compare_versions`, etc.)
|
||||||
|
- Remove `src/lib/versioningHelpers.ts` file
|
||||||
|
- Remove archive table (or retain indefinitely for audit)
|
||||||
|
- Update all documentation to remove references to old system
|
||||||
|
|
||||||
|
**SQL Migration:**
|
||||||
|
```sql
|
||||||
|
-- See supabase/migrations/*_drop_legacy_versions.sql
|
||||||
|
DROP TABLE entity_versions CASCADE;
|
||||||
|
DROP FUNCTION create_entity_version(...);
|
||||||
|
```
|
||||||
|
|
||||||
|
### 🚀 Phase 5: Optimization (Ongoing)
|
||||||
|
- Automated cleanup via pg_cron (monthly)
|
||||||
|
- Performance monitoring and index tuning
|
||||||
|
- Documentation updates based on usage patterns
|
||||||
|
- Version retention policy adjustments as needed
|
||||||
|
|
||||||
## Backfill Script (Optional)
|
## Backfill Script (Optional)
|
||||||
|
|
||||||
|
|||||||
@@ -1,3 +1,23 @@
|
|||||||
|
/**
|
||||||
|
* @deprecated This file uses the old JSONB-based versioning system.
|
||||||
|
*
|
||||||
|
* **Migration Notice:**
|
||||||
|
* The versioning system has been migrated to a pure relational structure.
|
||||||
|
* Triggers now automatically handle version creation - no manual calls needed.
|
||||||
|
*
|
||||||
|
* **New System:**
|
||||||
|
* - Versioning is automatic via database triggers
|
||||||
|
* - Use `useEntityVersions` hook for frontend access
|
||||||
|
* - Use `get_version_diff()` RPC for comparisons
|
||||||
|
* - Version tables: `park_versions`, `ride_versions`, etc.
|
||||||
|
*
|
||||||
|
* **Scheduled for Removal:** 2025-12-01
|
||||||
|
*
|
||||||
|
* @see docs/versioning/MIGRATION.md for migration guide
|
||||||
|
* @see docs/versioning/API.md for new API reference
|
||||||
|
* @see src/lib/versioningUtils.ts for modern utilities
|
||||||
|
*/
|
||||||
|
|
||||||
import { supabase } from '@/integrations/supabase/client';
|
import { supabase } from '@/integrations/supabase/client';
|
||||||
import { toast } from '@/hooks/use-toast';
|
import { toast } from '@/hooks/use-toast';
|
||||||
|
|
||||||
@@ -42,6 +62,12 @@ export async function captureCurrentState(
|
|||||||
|
|
||||||
/**
|
/**
|
||||||
* Create a new entity version with proper error handling
|
* Create a new entity version with proper error handling
|
||||||
|
*
|
||||||
|
* @deprecated Use automatic trigger-based versioning instead.
|
||||||
|
* This function calls the old JSONB-based `create_entity_version` RPC.
|
||||||
|
* Versions are now created automatically when entities are updated via triggers.
|
||||||
|
*
|
||||||
|
* @see docs/versioning/ARCHITECTURE.md for how triggers work
|
||||||
*/
|
*/
|
||||||
export async function createEntityVersion(params: {
|
export async function createEntityVersion(params: {
|
||||||
entityType: EntityType;
|
entityType: EntityType;
|
||||||
@@ -62,6 +88,11 @@ export async function createEntityVersion(params: {
|
|||||||
changeType = 'updated',
|
changeType = 'updated',
|
||||||
} = params;
|
} = params;
|
||||||
|
|
||||||
|
console.warn(
|
||||||
|
'⚠️ createEntityVersion is deprecated. Versioning is now automatic via triggers. ' +
|
||||||
|
'See docs/versioning/MIGRATION.md for migration guide.'
|
||||||
|
);
|
||||||
|
|
||||||
try {
|
try {
|
||||||
const { data, error } = await supabase.rpc('create_entity_version', {
|
const { data, error } = await supabase.rpc('create_entity_version', {
|
||||||
p_entity_type: entityType,
|
p_entity_type: entityType,
|
||||||
@@ -97,6 +128,9 @@ export async function createEntityVersion(params: {
|
|||||||
|
|
||||||
/**
|
/**
|
||||||
* Create entity version with audit log entry
|
* Create entity version with audit log entry
|
||||||
|
*
|
||||||
|
* @deprecated Use automatic trigger-based versioning instead.
|
||||||
|
* Versions are now created automatically when entities are updated.
|
||||||
*/
|
*/
|
||||||
export async function createEntityVersionWithAudit(
|
export async function createEntityVersionWithAudit(
|
||||||
params: {
|
params: {
|
||||||
@@ -137,6 +171,9 @@ export async function createEntityVersionWithAudit(
|
|||||||
|
|
||||||
/**
|
/**
|
||||||
* Rollback an entity to a previous version
|
* Rollback an entity to a previous version
|
||||||
|
*
|
||||||
|
* @deprecated This uses the old JSONB-based RPC.
|
||||||
|
* Use the relational `rollback_to_version()` RPC or `useEntityVersions` hook instead.
|
||||||
*/
|
*/
|
||||||
export async function rollbackToVersion(
|
export async function rollbackToVersion(
|
||||||
entityType: EntityType,
|
entityType: EntityType,
|
||||||
@@ -183,6 +220,9 @@ export async function rollbackToVersion(
|
|||||||
|
|
||||||
/**
|
/**
|
||||||
* Compare two versions and get the diff
|
* Compare two versions and get the diff
|
||||||
|
*
|
||||||
|
* @deprecated This uses the old JSONB-based RPC.
|
||||||
|
* Use `get_version_diff()` RPC or `useVersionComparison` hook instead.
|
||||||
*/
|
*/
|
||||||
export async function compareVersions(
|
export async function compareVersions(
|
||||||
fromVersionId: string,
|
fromVersionId: string,
|
||||||
|
|||||||
170
src/lib/versioningUtils.ts
Normal file
170
src/lib/versioningUtils.ts
Normal file
@@ -0,0 +1,170 @@
|
|||||||
|
/**
|
||||||
|
* Modern versioning utilities for relational version tables
|
||||||
|
*
|
||||||
|
* These functions work with the new trigger-based versioning system.
|
||||||
|
* All version creation is automatic via database triggers - no manual calls needed.
|
||||||
|
*
|
||||||
|
* @see docs/versioning/ARCHITECTURE.md for system design
|
||||||
|
* @see docs/versioning/API.md for complete API reference
|
||||||
|
*/
|
||||||
|
|
||||||
|
import { supabase } from '@/integrations/supabase/client';
|
||||||
|
import type { EntityType } from '@/types/versioning';
|
||||||
|
|
||||||
|
/**
|
||||||
|
* Manually trigger cleanup of old versions for a specific entity type
|
||||||
|
*
|
||||||
|
* Note: This should normally run automatically via pg_cron, but can be called manually.
|
||||||
|
*
|
||||||
|
* @param entityType - The entity type to clean up ('park', 'ride', 'company', 'ride_model')
|
||||||
|
* @param keepCount - Number of most recent versions to keep per entity (default: 50)
|
||||||
|
* @returns Number of versions deleted
|
||||||
|
*
|
||||||
|
* @example
|
||||||
|
* ```typescript
|
||||||
|
* const deleted = await cleanupVersions('park', 50);
|
||||||
|
* console.log(`Deleted ${deleted} old park versions`);
|
||||||
|
* ```
|
||||||
|
*/
|
||||||
|
export async function cleanupVersions(
|
||||||
|
entityType: EntityType,
|
||||||
|
keepCount: number = 50
|
||||||
|
): Promise<number> {
|
||||||
|
const { data, error } = await supabase.rpc('cleanup_old_versions', {
|
||||||
|
entity_type: entityType,
|
||||||
|
keep_versions: keepCount
|
||||||
|
});
|
||||||
|
|
||||||
|
if (error) {
|
||||||
|
console.error('Version cleanup failed:', error);
|
||||||
|
return 0;
|
||||||
|
}
|
||||||
|
|
||||||
|
return data as number;
|
||||||
|
}
|
||||||
|
|
||||||
|
/**
|
||||||
|
* Get statistics about versions for a specific entity
|
||||||
|
*
|
||||||
|
* @param entityType - The entity type ('park', 'ride', 'company', 'ride_model')
|
||||||
|
* @param entityId - The UUID of the entity
|
||||||
|
* @returns Version statistics including total count, date range, and change type distribution
|
||||||
|
*
|
||||||
|
* @example
|
||||||
|
* ```typescript
|
||||||
|
* const stats = await getVersionStats('park', 'uuid-here');
|
||||||
|
* console.log(`Total versions: ${stats.totalVersions}`);
|
||||||
|
* console.log(`Change types:`, stats.changeTypes);
|
||||||
|
* ```
|
||||||
|
*/
|
||||||
|
export async function getVersionStats(
|
||||||
|
entityType: EntityType,
|
||||||
|
entityId: string
|
||||||
|
) {
|
||||||
|
const versionTable = `${entityType}_versions`;
|
||||||
|
const entityIdCol = `${entityType}_id`;
|
||||||
|
|
||||||
|
const { data, error } = await supabase
|
||||||
|
.from(versionTable as any)
|
||||||
|
.select('version_number, created_at, change_type', { count: 'exact' })
|
||||||
|
.eq(entityIdCol, entityId)
|
||||||
|
.order('version_number', { ascending: true });
|
||||||
|
|
||||||
|
if (error || !data) {
|
||||||
|
console.error('Failed to fetch version stats:', error);
|
||||||
|
return null;
|
||||||
|
}
|
||||||
|
|
||||||
|
if (data.length === 0) {
|
||||||
|
return {
|
||||||
|
totalVersions: 0,
|
||||||
|
oldestVersion: null,
|
||||||
|
newestVersion: null,
|
||||||
|
changeTypes: {}
|
||||||
|
};
|
||||||
|
}
|
||||||
|
|
||||||
|
// Type-safe access to version data
|
||||||
|
const versions = data as unknown as Array<{
|
||||||
|
version_number: number;
|
||||||
|
created_at: string;
|
||||||
|
change_type: string;
|
||||||
|
}>;
|
||||||
|
|
||||||
|
return {
|
||||||
|
totalVersions: versions.length,
|
||||||
|
oldestVersion: versions[0]?.created_at || null,
|
||||||
|
newestVersion: versions[versions.length - 1]?.created_at || null,
|
||||||
|
changeTypes: versions.reduce((acc, v) => {
|
||||||
|
acc[v.change_type] = (acc[v.change_type] || 0) + 1;
|
||||||
|
return acc;
|
||||||
|
}, {} as Record<string, number>)
|
||||||
|
};
|
||||||
|
}
|
||||||
|
|
||||||
|
/**
|
||||||
|
* Get total version counts across all entity types
|
||||||
|
*
|
||||||
|
* Useful for monitoring storage usage and cleanup effectiveness.
|
||||||
|
*
|
||||||
|
* @returns Total version counts for each entity type
|
||||||
|
*
|
||||||
|
* @example
|
||||||
|
* ```typescript
|
||||||
|
* const counts = await getAllVersionCounts();
|
||||||
|
* console.log('Park versions:', counts.park);
|
||||||
|
* console.log('Ride versions:', counts.ride);
|
||||||
|
* ```
|
||||||
|
*/
|
||||||
|
export async function getAllVersionCounts() {
|
||||||
|
const counts = {
|
||||||
|
park: 0,
|
||||||
|
ride: 0,
|
||||||
|
company: 0,
|
||||||
|
ride_model: 0,
|
||||||
|
};
|
||||||
|
|
||||||
|
const parkCount = await supabase
|
||||||
|
.from('park_versions')
|
||||||
|
.select('*', { count: 'exact', head: true });
|
||||||
|
counts.park = parkCount.count || 0;
|
||||||
|
|
||||||
|
const rideCount = await supabase
|
||||||
|
.from('ride_versions')
|
||||||
|
.select('*', { count: 'exact', head: true });
|
||||||
|
counts.ride = rideCount.count || 0;
|
||||||
|
|
||||||
|
const companyCount = await supabase
|
||||||
|
.from('company_versions')
|
||||||
|
.select('*', { count: 'exact', head: true });
|
||||||
|
counts.company = companyCount.count || 0;
|
||||||
|
|
||||||
|
const modelCount = await supabase
|
||||||
|
.from('ride_model_versions')
|
||||||
|
.select('*', { count: 'exact', head: true });
|
||||||
|
counts.ride_model = modelCount.count || 0;
|
||||||
|
|
||||||
|
return counts;
|
||||||
|
}
|
||||||
|
|
||||||
|
/**
|
||||||
|
* Check if an entity has any versions
|
||||||
|
*
|
||||||
|
* @param entityType - The entity type
|
||||||
|
* @param entityId - The UUID of the entity
|
||||||
|
* @returns True if entity has at least one version
|
||||||
|
*/
|
||||||
|
export async function hasVersions(
|
||||||
|
entityType: EntityType,
|
||||||
|
entityId: string
|
||||||
|
): Promise<boolean> {
|
||||||
|
const versionTable = `${entityType}_versions`;
|
||||||
|
const entityIdCol = `${entityType}_id`;
|
||||||
|
|
||||||
|
const { count } = await supabase
|
||||||
|
.from(versionTable as any)
|
||||||
|
.select('*', { count: 'exact', head: true })
|
||||||
|
.eq(entityIdCol, entityId);
|
||||||
|
|
||||||
|
return (count || 0) > 0;
|
||||||
|
}
|
||||||
Reference in New Issue
Block a user