* Docker Infrastructure: - Multi-stage Dockerfile.dev with optimized Go proxy configuration - Complete compose.dev.yml with service orchestration - Fixed critical GOPROXY setting achieving 42x performance improvement - Migrated from Poetry to uv for faster Python package management * Build System Enhancements: - Enhanced Mage build system with caching and parallelization - Added incremental build capabilities with SHA256 checksums - Implemented parallel task execution with dependency resolution - Added comprehensive test orchestration targets * Testing Infrastructure: - Complete API testing suite with OpenAPI validation - Performance testing with multi-worker simulation - Integration testing for end-to-end workflows - Database testing with migration validation - Docker-based test environments * Documentation: - Comprehensive Docker development guides - Performance optimization case study - Build system architecture documentation - Test infrastructure usage guides * Performance Results: - Build time reduced from 60+ min failures to 9.5 min success - Go module downloads: 42x faster (84.2s vs 60+ min timeouts) - Success rate: 0% → 100% - Developer onboarding: days → 10 minutes Fixes critical Docker build failures and establishes production-ready containerized development environment with comprehensive testing.
193 lines
6.9 KiB
PL/PgSQL
193 lines
6.9 KiB
PL/PgSQL
-- Initialize test database for Flamenco testing
|
|
-- This script sets up the PostgreSQL database for advanced testing scenarios
|
|
|
|
-- Create test database if it doesn't exist
|
|
-- (This is handled by the POSTGRES_DB environment variable in docker-compose)
|
|
|
|
-- Create test user with necessary privileges
|
|
-- (This is handled by POSTGRES_USER and POSTGRES_PASSWORD in docker-compose)
|
|
|
|
-- Set up database configuration for testing
|
|
ALTER DATABASE flamenco_test SET timezone = 'UTC';
|
|
ALTER DATABASE flamenco_test SET log_statement = 'all';
|
|
ALTER DATABASE flamenco_test SET log_min_duration_statement = 100;
|
|
|
|
-- Create extensions that might be useful for testing
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
CREATE EXTENSION IF NOT EXISTS "pg_stat_statements";
|
|
|
|
-- Create schema for test data isolation
|
|
CREATE SCHEMA IF NOT EXISTS test_data;
|
|
|
|
-- Grant permissions to test user
|
|
GRANT ALL PRIVILEGES ON DATABASE flamenco_test TO flamenco_test;
|
|
GRANT ALL ON SCHEMA public TO flamenco_test;
|
|
GRANT ALL ON SCHEMA test_data TO flamenco_test;
|
|
|
|
-- Create test-specific tables for performance testing
|
|
CREATE TABLE IF NOT EXISTS test_data.performance_metrics (
|
|
id SERIAL PRIMARY KEY,
|
|
test_name VARCHAR(255) NOT NULL,
|
|
metric_name VARCHAR(255) NOT NULL,
|
|
metric_value NUMERIC NOT NULL,
|
|
recorded_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
test_run_id VARCHAR(255),
|
|
metadata JSONB
|
|
);
|
|
|
|
CREATE INDEX idx_performance_metrics_test_run ON test_data.performance_metrics(test_run_id);
|
|
CREATE INDEX idx_performance_metrics_name ON test_data.performance_metrics(test_name, metric_name);
|
|
|
|
-- Create test data fixtures table
|
|
CREATE TABLE IF NOT EXISTS test_data.fixtures (
|
|
id SERIAL PRIMARY KEY,
|
|
fixture_name VARCHAR(255) UNIQUE NOT NULL,
|
|
fixture_data JSONB NOT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
description TEXT
|
|
);
|
|
|
|
-- Insert common test fixtures
|
|
INSERT INTO test_data.fixtures (fixture_name, fixture_data, description) VALUES
|
|
('simple_blend_file',
|
|
'{"filepath": "/shared-storage/test-scenes/simple.blend", "frames": "1-10", "resolution": [1920, 1080]}',
|
|
'Simple Blender scene for basic rendering tests'),
|
|
('animation_blend_file',
|
|
'{"filepath": "/shared-storage/test-scenes/animation.blend", "frames": "1-120", "resolution": [1280, 720]}',
|
|
'Animation scene for testing longer render jobs'),
|
|
('high_res_blend_file',
|
|
'{"filepath": "/shared-storage/test-scenes/high-res.blend", "frames": "1-5", "resolution": [4096, 2160]}',
|
|
'High resolution scene for memory and performance testing');
|
|
|
|
-- Create test statistics table for tracking test runs
|
|
CREATE TABLE IF NOT EXISTS test_data.test_runs (
|
|
id SERIAL PRIMARY KEY,
|
|
run_id VARCHAR(255) UNIQUE NOT NULL,
|
|
test_suite VARCHAR(255) NOT NULL,
|
|
started_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
completed_at TIMESTAMP,
|
|
status VARCHAR(50) DEFAULT 'running',
|
|
total_tests INTEGER,
|
|
passed_tests INTEGER,
|
|
failed_tests INTEGER,
|
|
skipped_tests INTEGER,
|
|
metadata JSONB
|
|
);
|
|
|
|
-- Function to record test metrics
|
|
CREATE OR REPLACE FUNCTION test_data.record_metric(
|
|
p_test_name VARCHAR(255),
|
|
p_metric_name VARCHAR(255),
|
|
p_metric_value NUMERIC,
|
|
p_test_run_id VARCHAR(255) DEFAULT NULL,
|
|
p_metadata JSONB DEFAULT NULL
|
|
) RETURNS VOID AS $$
|
|
BEGIN
|
|
INSERT INTO test_data.performance_metrics (
|
|
test_name, metric_name, metric_value, test_run_id, metadata
|
|
) VALUES (
|
|
p_test_name, p_metric_name, p_metric_value, p_test_run_id, p_metadata
|
|
);
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Function to start a test run
|
|
CREATE OR REPLACE FUNCTION test_data.start_test_run(
|
|
p_run_id VARCHAR(255),
|
|
p_test_suite VARCHAR(255),
|
|
p_metadata JSONB DEFAULT NULL
|
|
) RETURNS VOID AS $$
|
|
BEGIN
|
|
INSERT INTO test_data.test_runs (run_id, test_suite, metadata)
|
|
VALUES (p_run_id, p_test_suite, p_metadata)
|
|
ON CONFLICT (run_id) DO UPDATE SET
|
|
started_at = CURRENT_TIMESTAMP,
|
|
status = 'running',
|
|
metadata = EXCLUDED.metadata;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Function to complete a test run
|
|
CREATE OR REPLACE FUNCTION test_data.complete_test_run(
|
|
p_run_id VARCHAR(255),
|
|
p_status VARCHAR(50),
|
|
p_total_tests INTEGER DEFAULT NULL,
|
|
p_passed_tests INTEGER DEFAULT NULL,
|
|
p_failed_tests INTEGER DEFAULT NULL,
|
|
p_skipped_tests INTEGER DEFAULT NULL
|
|
) RETURNS VOID AS $$
|
|
BEGIN
|
|
UPDATE test_data.test_runs SET
|
|
completed_at = CURRENT_TIMESTAMP,
|
|
status = p_status,
|
|
total_tests = COALESCE(p_total_tests, total_tests),
|
|
passed_tests = COALESCE(p_passed_tests, passed_tests),
|
|
failed_tests = COALESCE(p_failed_tests, failed_tests),
|
|
skipped_tests = COALESCE(p_skipped_tests, skipped_tests)
|
|
WHERE run_id = p_run_id;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Create views for test reporting
|
|
CREATE OR REPLACE VIEW test_data.test_summary AS
|
|
SELECT
|
|
test_suite,
|
|
COUNT(*) as total_runs,
|
|
COUNT(*) FILTER (WHERE status = 'passed') as passed_runs,
|
|
COUNT(*) FILTER (WHERE status = 'failed') as failed_runs,
|
|
AVG(EXTRACT(EPOCH FROM (completed_at - started_at))) as avg_duration_seconds,
|
|
MAX(completed_at) as last_run
|
|
FROM test_data.test_runs
|
|
WHERE completed_at IS NOT NULL
|
|
GROUP BY test_suite;
|
|
|
|
CREATE OR REPLACE VIEW test_data.performance_summary AS
|
|
SELECT
|
|
test_name,
|
|
metric_name,
|
|
COUNT(*) as sample_count,
|
|
AVG(metric_value) as avg_value,
|
|
MIN(metric_value) as min_value,
|
|
MAX(metric_value) as max_value,
|
|
PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY metric_value) as median_value,
|
|
PERCENTILE_CONT(0.95) WITHIN GROUP (ORDER BY metric_value) as p95_value,
|
|
STDDEV(metric_value) as stddev_value
|
|
FROM test_data.performance_metrics
|
|
GROUP BY test_name, metric_name;
|
|
|
|
-- Grant access to test functions and views
|
|
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA test_data TO flamenco_test;
|
|
GRANT SELECT ON ALL TABLES IN SCHEMA test_data TO flamenco_test;
|
|
GRANT SELECT ON test_data.test_summary TO flamenco_test;
|
|
GRANT SELECT ON test_data.performance_summary TO flamenco_test;
|
|
|
|
-- Create cleanup function to reset test data
|
|
CREATE OR REPLACE FUNCTION test_data.cleanup_old_test_data(retention_days INTEGER DEFAULT 7)
|
|
RETURNS INTEGER AS $$
|
|
DECLARE
|
|
deleted_count INTEGER;
|
|
BEGIN
|
|
DELETE FROM test_data.performance_metrics
|
|
WHERE recorded_at < CURRENT_TIMESTAMP - INTERVAL '1 day' * retention_days;
|
|
|
|
GET DIAGNOSTICS deleted_count = ROW_COUNT;
|
|
|
|
DELETE FROM test_data.test_runs
|
|
WHERE started_at < CURRENT_TIMESTAMP - INTERVAL '1 day' * retention_days;
|
|
|
|
RETURN deleted_count;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Set up automatic cleanup (optional, uncomment if needed)
|
|
-- This would require pg_cron extension
|
|
-- SELECT cron.schedule('cleanup-test-data', '0 2 * * *', 'SELECT test_data.cleanup_old_test_data(7);');
|
|
|
|
-- Log initialization completion
|
|
DO $$
|
|
BEGIN
|
|
RAISE NOTICE 'Test database initialization completed successfully';
|
|
RAISE NOTICE 'Available schemas: public, test_data';
|
|
RAISE NOTICE 'Test functions: start_test_run, complete_test_run, record_metric, cleanup_old_test_data';
|
|
RAISE NOTICE 'Test views: test_summary, performance_summary';
|
|
END $$; |