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_users"); $pdo->exec("DROP TABLE IF EXISTS test_products"); $pdo->exec("DROP TABLE IF EXISTS test_orders"); $pdo->exec("DROP TABLE IF EXISTS test_documents"); echo "✅ Cleanup complete\n\n"; // Test 1: String concatenation (full name from first + last name) echo "Test 1: String Concatenation\n"; echo "=============================\n"; $pdo->exec(" CREATE TABLE test_users ( id SERIAL PRIMARY KEY, first_name VARCHAR(100) NOT NULL, last_name VARCHAR(100) NOT NULL, full_name VARCHAR(201) GENERATED ALWAYS AS (first_name || ' ' || last_name) STORED, email VARCHAR(200) NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ) "); echo "✅ Table created with generated full_name column\n"; // Insert data $pdo->exec(" INSERT INTO test_users (first_name, last_name, email) VALUES ('John', 'Doe', 'john.doe@example.com'), ('Jane', 'Smith', 'jane.smith@example.com'), ('Bob', 'Johnson', 'bob.johnson@example.com') "); echo "✅ Test users inserted\n"; // Query generated columns $stmt = $pdo->query("SELECT first_name, last_name, full_name FROM test_users ORDER BY id"); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Generated full names:\n"; foreach ($results as $row) { echo " - {$row['first_name']} {$row['last_name']} → {$row['full_name']}\n"; } echo "\n"; // Test auto-update: Update first_name and verify full_name updates echo "Testing auto-update: Changing John's last name...\n"; $pdo->exec("UPDATE test_users SET last_name = 'Williams' WHERE first_name = 'John'"); $stmt = $pdo->query("SELECT full_name FROM test_users WHERE first_name = 'John'"); $result = $stmt->fetch(PDO::FETCH_ASSOC); echo " New full name: {$result['full_name']}\n"; echo "✅ Generated column auto-updated\n\n"; // Test 2: Mathematical calculations echo "Test 2: Mathematical Calculations\n"; echo "==================================\n"; $pdo->exec(" CREATE TABLE test_products ( id SERIAL PRIMARY KEY, name VARCHAR(200) NOT NULL, price NUMERIC(10,2) NOT NULL, tax_rate NUMERIC(5,4) NOT NULL DEFAULT 0.19, price_incl_tax NUMERIC(10,2) GENERATED ALWAYS AS (price * (1 + tax_rate)) STORED, discount_percent INTEGER DEFAULT 0, final_price NUMERIC(10,2) GENERATED ALWAYS AS ( price * (1 + tax_rate) * (1 - discount_percent / 100.0) ) STORED, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ) "); echo "✅ Table created with calculated price columns\n"; // Insert products $pdo->exec(" INSERT INTO test_products (name, price, tax_rate, discount_percent) VALUES ('Laptop', 999.99, 0.19, 10), ('Mouse', 29.99, 0.19, 0), ('Keyboard', 79.99, 0.19, 15) "); echo "✅ Test products inserted\n"; // Query calculated prices $stmt = $pdo->query(" SELECT name, price, tax_rate, discount_percent, price_incl_tax, final_price FROM test_products ORDER BY id "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Calculated prices:\n"; foreach ($results as $row) { echo " - {$row['name']}\n"; echo " Base: €{$row['price']}, Tax: {$row['tax_rate']}, Discount: {$row['discount_percent']}%\n"; echo " With tax: €{$row['price_incl_tax']}, Final: €{$row['final_price']}\n\n"; } // Test 3: Status calculation based on numeric values echo "Test 3: Numeric Status Calculation\n"; echo "===================================\n"; $pdo->exec(" CREATE TABLE test_orders ( id SERIAL PRIMARY KEY, order_number VARCHAR(50) NOT NULL, total_amount NUMERIC(10,2) NOT NULL, items_count INTEGER NOT NULL, average_item_price NUMERIC(10,2) GENERATED ALWAYS AS ( total_amount / NULLIF(items_count, 0) ) STORED, order_status VARCHAR(20) GENERATED ALWAYS AS ( CASE WHEN total_amount < 50 THEN 'small' WHEN total_amount < 200 THEN 'medium' ELSE 'large' END ) STORED, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ) "); echo "✅ Table created with calculated status columns\n"; // Insert orders $pdo->exec(" INSERT INTO test_orders (order_number, total_amount, items_count) VALUES ('ORD-001', 29.99, 2), ('ORD-002', 149.50, 5), ('ORD-003', 599.99, 3) "); echo "✅ Test orders inserted\n"; // Query calculated values $stmt = $pdo->query(" SELECT order_number, total_amount, items_count, average_item_price, order_status FROM test_orders ORDER BY id "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Calculated order statistics:\n"; foreach ($results as $row) { echo " - {$row['order_number']}: Total €{$row['total_amount']}, "; echo "{$row['items_count']} items, Avg €{$row['average_item_price']} → Status: {$row['order_status']}\n"; } echo "\n"; // Test 4: JSONB field extraction echo "Test 4: JSONB Field Extraction\n"; echo "===============================\n"; $pdo->exec(" CREATE TABLE test_documents ( id SERIAL PRIMARY KEY, title VARCHAR(200) NOT NULL, metadata JSONB NOT NULL, author VARCHAR(200) GENERATED ALWAYS AS (metadata->>'author') STORED, created_year INTEGER GENERATED ALWAYS AS ((metadata->>'year')::INTEGER) STORED, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ) "); echo "✅ Table created with JSONB extraction columns\n"; // Insert documents $pdo->exec(" INSERT INTO test_documents (title, metadata) VALUES ('The Art of Programming', '{\"author\": \"Donald Knuth\", \"year\": 1968, \"pages\": 650}'), ('Clean Code', '{\"author\": \"Robert C. Martin\", \"year\": 2008, \"pages\": 464}'), ('Design Patterns', '{\"author\": \"Gang of Four\", \"year\": 1994, \"pages\": 395}') "); echo "✅ Test documents inserted\n"; // Query extracted fields $stmt = $pdo->query(" SELECT title, author, created_year FROM test_documents ORDER BY created_year "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Extracted JSONB fields:\n"; foreach ($results as $row) { echo " - {$row['title']} by {$row['author']} ({$row['created_year']})\n"; } echo "\n"; // Test 5: Cannot manually update generated columns echo "Test 5: Immutability Test (Generated Columns Cannot Be Updated)\n"; echo "================================================================\n"; try { $pdo->exec("UPDATE test_users SET full_name = 'Manual Name' WHERE id = 1"); echo "❌ ERROR: Should not allow manual updates to generated columns\n"; } catch (\PDOException $e) { if (str_contains($e->getMessage(), 'cannot insert a non-DEFAULT value into column') || str_contains($e->getMessage(), 'column') && str_contains($e->getMessage(), 'can only be updated to DEFAULT')) { echo "✅ Correctly prevented manual update of generated column\n"; echo " Error message: " . $e->getMessage() . "\n\n"; } else { throw $e; } } // Test 6: Complex expression with CASE (referencing base columns, not generated columns) echo "Test 6: Complex Expression with CASE\n"; echo "=====================================\n"; $pdo->exec("ALTER TABLE test_products ADD COLUMN price_category VARCHAR(20) GENERATED ALWAYS AS ( CASE WHEN (price * (1 + tax_rate) * (1 - discount_percent / 100.0)) < 50 THEN 'Budget' WHEN (price * (1 + tax_rate) * (1 - discount_percent / 100.0)) < 200 THEN 'Mid-Range' ELSE 'Premium' END ) STORED"); echo "✅ Added price_category generated column with CASE expression\n"; // Query categorized products $stmt = $pdo->query(" SELECT name, final_price, price_category FROM test_products ORDER BY final_price "); $results = $stmt->fetchAll(PDO::FETCH_ASSOC); echo " Product categories:\n"; foreach ($results as $row) { echo " - {$row['name']}: €{$row['final_price']} → {$row['price_category']}\n"; } echo "\n"; // Cleanup echo "Cleaning up...\n"; $pdo->exec("DROP TABLE IF EXISTS test_users"); $pdo->exec("DROP TABLE IF EXISTS test_products"); $pdo->exec("DROP TABLE IF EXISTS test_orders"); $pdo->exec("DROP TABLE IF EXISTS test_documents"); echo "✅ Test tables dropped\n"; echo "\n✅ All Generated Column tests passed!\n"; echo "\nSummary:\n"; echo "========\n"; echo "✅ GENERATED ALWAYS AS ... STORED syntax works\n"; echo "✅ String concatenation in generated columns works\n"; echo "✅ Mathematical calculations work\n"; echo "✅ Numeric status calculations work\n"; echo "✅ JSONB field extraction works\n"; echo "✅ Complex CASE expressions work\n"; echo "✅ Generated columns auto-update when source columns change\n"; echo "✅ Generated columns cannot be manually updated (immutable)\n"; echo "✅ Generated columns can be added with ALTER TABLE\n"; } catch (\Exception $e) { echo "❌ Error: " . $e->getMessage() . "\n"; echo "Stack trace:\n" . $e->getTraceAsString() . "\n"; exit(1); }