setAttribute(PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION); echo "✅ Database connection established\n\n"; // Cleanup echo "Cleaning up existing test tables...\n"; $pdo->exec("DROP TABLE IF EXISTS test_products"); $pdo->exec("DROP TABLE IF EXISTS test_user_permissions"); $pdo->exec("DROP TABLE IF EXISTS test_time_series"); echo "✅ Cleanup complete\n\n"; // Test 1: Create table with INTEGER[] column echo "Test 1: INTEGER[] Array Column\n"; echo "==============================\n"; $pdo->exec(" CREATE TABLE test_products ( id SERIAL PRIMARY KEY, name VARCHAR(100) NOT NULL, category_ids INTEGER[] NOT NULL, tags TEXT[] DEFAULT '{}', prices NUMERIC(10,2)[] DEFAULT '{}', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ) "); echo "✅ Table created with INTEGER[], TEXT[], and NUMERIC[] columns\n"; // Create GIN index on tags array for fast containment queries $pdo->exec("CREATE INDEX idx_products_tags ON test_products USING GIN (tags)"); echo "✅ GIN index created on TEXT[] column\n\n"; // Insert data with arrays echo "Inserting test data...\n"; $pdo->exec(" INSERT INTO test_products (name, category_ids, tags, prices) VALUES ('Laptop', '{1, 5, 12}', '{\"electronics\", \"computers\", \"featured\"}', '{999.99, 899.99, 799.99}'), ('Mouse', '{1, 5}', '{\"electronics\", \"accessories\"}', '{29.99, 24.99}'), ('Keyboard', '{1, 5}', '{\"electronics\", \"accessories\", \"featured\"}', '{79.99, 69.99}'), ('Monitor', '{1, 5, 12}', '{\"electronics\", \"display\"}', '{299.99, 249.99}'), ('Desk', '{8}', '{\"furniture\", \"office\"}', '{199.99}') "); echo "✅ Test data inserted\n\n"; // Query 1: Find products in specific categories using ANY echo "Query 1: Products in category 5 (using ANY operator)\n"; $stmt = $pdo->query(" SELECT name, category_ids FROM test_products WHERE 5 = ANY(category_ids) "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Found " . count($results) . " products:\n"; foreach ($results as $row) { $cats = str_replace(['{', '}'], ['[', ']'], $row['category_ids']); echo " - {$row['name']}: Categories {$cats}\n"; } echo "\n"; // Query 2: Find products with ALL categories echo "Query 2: Products with categories 1 AND 5 (using @> operator)\n"; $stmt = $pdo->query(" SELECT name, category_ids FROM test_products WHERE category_ids @> '{1, 5}' "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Found " . count($results) . " products:\n"; foreach ($results as $row) { $cats = str_replace(['{', '}'], ['[', ']'], $row['category_ids']); echo " - {$row['name']}: Categories {$cats}\n"; } echo "\n"; // Query 3: Find products with overlapping categories echo "Query 3: Products with overlapping categories (using && operator)\n"; $stmt = $pdo->query(" SELECT name, category_ids FROM test_products WHERE category_ids && '{5, 12}' "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Found " . count($results) . " products:\n"; foreach ($results as $row) { $cats = str_replace(['{', '}'], ['[', ']'], $row['category_ids']); echo " - {$row['name']}: Categories {$cats}\n"; } echo "\n"; // Query 4: Find products with specific tags echo "Query 4: Products with 'featured' tag\n"; $stmt = $pdo->query(" SELECT name, tags FROM test_products WHERE 'featured' = ANY(tags) "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Found " . count($results) . " products:\n"; foreach ($results as $row) { $tags = str_replace(['{', '}'], ['[', ']'], $row['tags']); echo " - {$row['name']}: Tags {$tags}\n"; } echo "\n"; // Query 5: Array functions echo "Query 5: Array length and element access\n"; $stmt = $pdo->query(" SELECT name, array_length(category_ids, 1) as cat_count, category_ids[1] as first_category, prices[1] as first_price FROM test_products WHERE array_length(category_ids, 1) > 2 "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Found " . count($results) . " products with >2 categories:\n"; foreach ($results as $row) { echo " - {$row['name']}: {$row['cat_count']} categories, first: {$row['first_category']}, price: \${$row['first_price']}\n"; } echo "\n"; // Query 6: Unnest array to rows echo "Query 6: Unnest categories (array to rows)\n"; $stmt = $pdo->query(" SELECT name, unnest(category_ids) as category_id FROM test_products WHERE name = 'Laptop' "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Laptop categories:\n"; foreach ($results as $row) { echo " - Category ID: {$row['category_id']}\n"; } echo "\n"; // Test 2: UUID[] Array Column echo "\nTest 2: UUID[] Array Column\n"; echo "===========================\n"; $pdo->exec(" CREATE TABLE test_user_permissions ( id SERIAL PRIMARY KEY, username VARCHAR(100) NOT NULL, role_ids UUID[] NOT NULL DEFAULT '{}', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ) "); echo "✅ Table created with UUID[] column\n"; // Insert data with UUID arrays $pdo->exec(" INSERT INTO test_user_permissions (username, role_ids) VALUES ('admin', '{\"550e8400-e29b-41d4-a716-446655440000\", \"550e8400-e29b-41d4-a716-446655440001\"}'), ('editor', '{\"550e8400-e29b-41d4-a716-446655440001\"}'), ('viewer', '{\"550e8400-e29b-41d4-a716-446655440002\"}') "); echo "✅ Data inserted with UUID arrays\n"; // Query UUID arrays $stmt = $pdo->query(" SELECT username, array_length(role_ids, 1) as role_count FROM test_user_permissions ORDER BY role_count DESC "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Users by role count:\n"; foreach ($results as $row) { echo " - {$row['username']}: {$row['role_count']} role(s)\n"; } echo "\n"; // Test 3: TIMESTAMP[] Array Column echo "\nTest 3: TIMESTAMP[] Array Column\n"; echo "=================================\n"; $pdo->exec(" CREATE TABLE test_time_series ( id SERIAL PRIMARY KEY, sensor_name VARCHAR(100) NOT NULL, readings NUMERIC(10,2)[] NOT NULL, timestamps TIMESTAMP[] NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ) "); echo "✅ Table created with TIMESTAMP[] column\n"; // Insert time series data $pdo->exec(" INSERT INTO test_time_series (sensor_name, readings, timestamps) VALUES ('Temperature Sensor 1', '{20.5, 21.2, 22.1, 21.8}', '{\"2025-01-11 10:00:00\", \"2025-01-11 11:00:00\", \"2025-01-11 12:00:00\", \"2025-01-11 13:00:00\"}') "); echo "✅ Time series data inserted\n"; // Query time series data $stmt = $pdo->query(" SELECT sensor_name, array_length(readings, 1) as reading_count, readings[1] as first_reading, timestamps[1] as first_timestamp FROM test_time_series "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); foreach ($results as $row) { echo " Sensor: {$row['sensor_name']}\n"; echo " Total readings: {$row['reading_count']}\n"; echo " First reading: {$row['first_reading']}°C at {$row['first_timestamp']}\n"; } echo "\n"; // Test 4: Array aggregation echo "\nTest 4: Array Aggregation\n"; echo "=========================\n"; $stmt = $pdo->query(" SELECT array_agg(name ORDER BY name) as product_names, array_agg(DISTINCT category_ids[1]) as unique_first_categories FROM test_products "); $result = $stmt->fetch(PDO::FETCH_ASSOC); $names = str_replace(['{', '}'], ['[', ']'], $result['product_names']); $cats = str_replace(['{', '}'], ['[', ']'], $result['unique_first_categories']); echo " All product names: {$names}\n"; echo " Unique first categories: {$cats}\n\n"; // Test 5: Array modification functions echo "\nTest 5: Array Modification Functions\n"; echo "=====================================\n"; // Array append echo "Array append example:\n"; $pdo->exec(" UPDATE test_products SET tags = array_append(tags, 'bestseller') WHERE name = 'Laptop' "); $stmt = $pdo->query("SELECT tags FROM test_products WHERE name = 'Laptop'"); $result = $stmt->fetch(PDO::FETCH_ASSOC); $tags = str_replace(['{', '}'], ['[', ']'], $result['tags']); echo " Laptop tags after append: {$tags}\n"; // Array remove echo "\nArray remove example:\n"; $pdo->exec(" UPDATE test_products SET tags = array_remove(tags, 'bestseller') WHERE name = 'Laptop' "); $stmt = $pdo->query("SELECT tags FROM test_products WHERE name = 'Laptop'"); $result = $stmt->fetch(PDO::FETCH_ASSOC); $tags = str_replace(['{', '}'], ['[', ']'], $result['tags']); echo " Laptop tags after remove: {$tags}\n"; // Array concatenation echo "\nArray concatenation example:\n"; $stmt = $pdo->query(" SELECT name, tags || '{\"new\", \"special\"}' as combined_tags FROM test_products WHERE name = 'Mouse' "); $result = $stmt->fetch(PDO::FETCH_ASSOC); $tags = str_replace(['{', '}'], ['[', ']'], $result['combined_tags']); echo " Mouse combined tags: {$tags}\n\n"; // Cleanup echo "Cleaning up...\n"; $pdo->exec("DROP TABLE IF EXISTS test_products"); $pdo->exec("DROP TABLE IF EXISTS test_user_permissions"); $pdo->exec("DROP TABLE IF EXISTS test_time_series"); echo "✅ Test tables dropped\n"; echo "\n✅ All Array Column tests passed!\n"; echo "\nSummary:\n"; echo "========\n"; echo "✅ INTEGER[] array columns work\n"; echo "✅ TEXT[] array columns work\n"; echo "✅ NUMERIC[] array columns work\n"; echo "✅ UUID[] array columns work\n"; echo "✅ TIMESTAMP[] array columns work\n"; echo "✅ GIN indexes on arrays work\n"; echo "✅ Array operators (@>, &&, ANY) work\n"; echo "✅ Array functions (array_length, unnest, array_agg) work\n"; echo "✅ Array modification (array_append, array_remove, ||) works\n"; echo "✅ Array element access with [index] works\n"; } catch (\Exception $e) { echo "❌ Error: " . $e->getMessage() . "\n"; echo "Stack trace:\n" . $e->getTraceAsString() . "\n"; exit(1); }