- Add comprehensive health check system with multiple endpoints - Add Prometheus metrics endpoint - Add production logging configurations (5 strategies) - Add complete deployment documentation suite: * QUICKSTART.md - 30-minute deployment guide * DEPLOYMENT_CHECKLIST.md - Printable verification checklist * DEPLOYMENT_WORKFLOW.md - Complete deployment lifecycle * PRODUCTION_DEPLOYMENT.md - Comprehensive technical reference * production-logging.md - Logging configuration guide * ANSIBLE_DEPLOYMENT.md - Infrastructure as Code automation * README.md - Navigation hub * DEPLOYMENT_SUMMARY.md - Executive summary - Add deployment scripts and automation - Add DEPLOYMENT_PLAN.md - Concrete plan for immediate deployment - Update README with production-ready features All production infrastructure is now complete and ready for deployment.
281 lines
11 KiB
PHP
281 lines
11 KiB
PHP
<?php
|
|
|
|
declare(strict_types=1);
|
|
|
|
echo "Testing PostgreSQL Full-Text Search with tsvector\n";
|
|
echo "==================================================\n\n";
|
|
|
|
try {
|
|
// Create PDO connection
|
|
$pdo = new PDO(
|
|
'pgsql:host=db;dbname=michaelschiemer',
|
|
'postgres',
|
|
'StartSimple2024!'
|
|
);
|
|
$pdo->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_articles");
|
|
$pdo->exec("DROP TABLE IF EXISTS test_products_fts");
|
|
echo "✅ Cleanup complete\n\n";
|
|
|
|
// Test 1: Basic tsvector column with manual updates
|
|
echo "Test 1: Basic TSVECTOR Column\n";
|
|
echo "==============================\n";
|
|
$pdo->exec("
|
|
CREATE TABLE test_articles (
|
|
id SERIAL PRIMARY KEY,
|
|
title VARCHAR(200) NOT NULL,
|
|
content TEXT NOT NULL,
|
|
search_vector TSVECTOR,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
)
|
|
");
|
|
echo "✅ Table created with TSVECTOR column\n";
|
|
|
|
// Create GIN index on tsvector column
|
|
$pdo->exec("CREATE INDEX idx_articles_search ON test_articles USING GIN (search_vector)");
|
|
echo "✅ GIN index created on TSVECTOR column\n\n";
|
|
|
|
// Insert articles with tsvector data
|
|
echo "Inserting test articles...\n";
|
|
$pdo->exec("
|
|
INSERT INTO test_articles (title, content, search_vector) VALUES
|
|
(
|
|
'PostgreSQL Full-Text Search',
|
|
'PostgreSQL provides powerful full-text search capabilities. It supports stemming, ranking, and phrase search.',
|
|
to_tsvector('english', 'PostgreSQL Full-Text Search PostgreSQL provides powerful full-text search capabilities. It supports stemming, ranking, and phrase search.')
|
|
),
|
|
(
|
|
'Database Indexing Strategies',
|
|
'Proper indexing is crucial for database performance. B-tree indexes are the default, but GIN indexes excel for full-text search.',
|
|
to_tsvector('english', 'Database Indexing Strategies Proper indexing is crucial for database performance. B-tree indexes are the default, but GIN indexes excel for full-text search.')
|
|
),
|
|
(
|
|
'NoSQL vs SQL Databases',
|
|
'SQL databases like PostgreSQL offer ACID guarantees. NoSQL databases prioritize scalability and flexibility.',
|
|
to_tsvector('english', 'NoSQL vs SQL Databases SQL databases like PostgreSQL offer ACID guarantees. NoSQL databases prioritize scalability and flexibility.')
|
|
),
|
|
(
|
|
'Web Development with PHP',
|
|
'PHP is a popular server-side scripting language. Modern PHP frameworks provide robust tools for web development.',
|
|
to_tsvector('english', 'Web Development with PHP PHP is a popular server-side scripting language. Modern PHP frameworks provide robust tools for web development.')
|
|
)
|
|
");
|
|
echo "✅ Test articles inserted\n\n";
|
|
|
|
// Query 1: Simple full-text search
|
|
echo "Query 1: Search for 'postgresql'\n";
|
|
$stmt = $pdo->query("
|
|
SELECT title, ts_rank(search_vector, to_tsquery('english', 'postgresql')) as rank
|
|
FROM test_articles
|
|
WHERE search_vector @@ to_tsquery('english', 'postgresql')
|
|
ORDER BY rank DESC
|
|
");
|
|
$results = $stmt->fetchAll(PDO::FETCH_ASSOC);
|
|
echo " Found " . count($results) . " articles:\n";
|
|
foreach ($results as $row) {
|
|
echo sprintf(" - %s (rank: %.4f)\n", $row['title'], $row['rank']);
|
|
}
|
|
echo "\n";
|
|
|
|
// Query 2: Boolean full-text search (AND)
|
|
echo "Query 2: Search for 'database & index'\n";
|
|
$stmt = $pdo->query("
|
|
SELECT title, ts_rank(search_vector, to_tsquery('english', 'database & index')) as rank
|
|
FROM test_articles
|
|
WHERE search_vector @@ to_tsquery('english', 'database & index')
|
|
ORDER BY rank DESC
|
|
");
|
|
$results = $stmt->fetchAll(PDO::FETCH_ASSOC);
|
|
echo " Found " . count($results) . " articles:\n";
|
|
foreach ($results as $row) {
|
|
echo sprintf(" - %s (rank: %.4f)\n", $row['title'], $row['rank']);
|
|
}
|
|
echo "\n";
|
|
|
|
// Query 3: Boolean full-text search (OR)
|
|
echo "Query 3: Search for 'php | python'\n";
|
|
$stmt = $pdo->query("
|
|
SELECT title, ts_rank(search_vector, to_tsquery('english', 'php | python')) as rank
|
|
FROM test_articles
|
|
WHERE search_vector @@ to_tsquery('english', 'php | python')
|
|
ORDER BY rank DESC
|
|
");
|
|
$results = $stmt->fetchAll(PDO::FETCH_ASSOC);
|
|
echo " Found " . count($results) . " articles:\n";
|
|
foreach ($results as $row) {
|
|
echo sprintf(" - %s (rank: %.4f)\n", $row['title'], $row['rank']);
|
|
}
|
|
echo "\n";
|
|
|
|
// Query 4: Negation in full-text search
|
|
echo "Query 4: Search for 'database & !nosql'\n";
|
|
$stmt = $pdo->query("
|
|
SELECT title, ts_rank(search_vector, to_tsquery('english', 'database & !nosql')) as rank
|
|
FROM test_articles
|
|
WHERE search_vector @@ to_tsquery('english', 'database & !nosql')
|
|
ORDER BY rank DESC
|
|
");
|
|
$results = $stmt->fetchAll(PDO::FETCH_ASSOC);
|
|
echo " Found " . count($results) . " articles:\n";
|
|
foreach ($results as $row) {
|
|
echo sprintf(" - %s (rank: %.4f)\n", $row['title'], $row['rank']);
|
|
}
|
|
echo "\n";
|
|
|
|
// Query 5: Phrase search
|
|
echo "Query 5: Phrase search 'full-text search'\n";
|
|
$stmt = $pdo->query("
|
|
SELECT title, ts_rank(search_vector, phraseto_tsquery('english', 'full-text search')) as rank
|
|
FROM test_articles
|
|
WHERE search_vector @@ phraseto_tsquery('english', 'full-text search')
|
|
ORDER BY rank DESC
|
|
");
|
|
$results = $stmt->fetchAll(PDO::FETCH_ASSOC);
|
|
echo " Found " . count($results) . " articles:\n";
|
|
foreach ($results as $row) {
|
|
echo sprintf(" - %s (rank: %.4f)\n", $row['title'], $row['rank']);
|
|
}
|
|
echo "\n";
|
|
|
|
// Query 6: Headline generation (search result highlighting)
|
|
echo "Query 6: Search with headline highlighting\n";
|
|
$stmt = $pdo->query("
|
|
SELECT
|
|
title,
|
|
ts_headline('english', content, to_tsquery('english', 'search'), 'MaxWords=20, MinWords=10') as snippet
|
|
FROM test_articles
|
|
WHERE search_vector @@ to_tsquery('english', 'search')
|
|
LIMIT 2
|
|
");
|
|
$results = $stmt->fetchAll(PDO::FETCH_ASSOC);
|
|
echo " Results with highlighted snippets:\n";
|
|
foreach ($results as $row) {
|
|
echo " - {$row['title']}\n";
|
|
echo " Snippet: {$row['snippet']}\n\n";
|
|
}
|
|
|
|
// Test 2: Generated column for automatic tsvector updates
|
|
echo "\nTest 2: Generated TSVECTOR Column (Auto-Update)\n";
|
|
echo "================================================\n";
|
|
$pdo->exec("
|
|
CREATE TABLE test_products_fts (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(200) NOT NULL,
|
|
description TEXT NOT NULL,
|
|
search_vector TSVECTOR GENERATED ALWAYS AS (
|
|
to_tsvector('english', name || ' ' || description)
|
|
) STORED,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
)
|
|
");
|
|
echo "✅ Table created with auto-updating TSVECTOR generated column\n";
|
|
|
|
// Create GIN index
|
|
$pdo->exec("CREATE INDEX idx_products_search ON test_products_fts USING GIN (search_vector)");
|
|
echo "✅ GIN index created\n\n";
|
|
|
|
// Insert products (tsvector auto-updates)
|
|
echo "Inserting test products...\n";
|
|
$pdo->exec("
|
|
INSERT INTO test_products_fts (name, description) VALUES
|
|
('Wireless Mouse', 'Ergonomic wireless mouse with precision tracking and long battery life'),
|
|
('Mechanical Keyboard', 'RGB mechanical gaming keyboard with cherry MX switches'),
|
|
('USB-C Cable', 'High-speed USB-C charging cable with data transfer support'),
|
|
('Laptop Stand', 'Adjustable aluminum laptop stand for ergonomic workspace')
|
|
");
|
|
echo "✅ Test products inserted (tsvector automatically populated)\n\n";
|
|
|
|
// Query products
|
|
echo "Query: Search for 'wireless'\n";
|
|
$stmt = $pdo->query("
|
|
SELECT name, ts_rank(search_vector, to_tsquery('english', 'wireless')) as rank
|
|
FROM test_products_fts
|
|
WHERE search_vector @@ to_tsquery('english', 'wireless')
|
|
ORDER BY rank DESC
|
|
");
|
|
$results = $stmt->fetchAll(PDO::FETCH_ASSOC);
|
|
echo " Found " . count($results) . " products:\n";
|
|
foreach ($results as $row) {
|
|
echo sprintf(" - %s (rank: %.4f)\n", $row['name'], $row['rank']);
|
|
}
|
|
echo "\n";
|
|
|
|
// Test auto-update: Update product and verify tsvector updates
|
|
echo "Testing auto-update: Updating product description...\n";
|
|
$pdo->exec("
|
|
UPDATE test_products_fts
|
|
SET description = 'Bluetooth wireless mouse with precision optical tracking'
|
|
WHERE name = 'Wireless Mouse'
|
|
");
|
|
|
|
// Query again for 'bluetooth'
|
|
$stmt = $pdo->query("
|
|
SELECT name, ts_rank(search_vector, to_tsquery('english', 'bluetooth')) as rank
|
|
FROM test_products_fts
|
|
WHERE search_vector @@ to_tsquery('english', 'bluetooth')
|
|
ORDER BY rank DESC
|
|
");
|
|
$results = $stmt->fetchAll(PDO::FETCH_ASSOC);
|
|
echo " Products with 'bluetooth' after update:\n";
|
|
foreach ($results as $row) {
|
|
echo sprintf(" - %s (rank: %.4f)\n", $row['name'], $row['rank']);
|
|
}
|
|
echo "✅ Generated column auto-updated correctly\n\n";
|
|
|
|
// Test 3: Multi-language support
|
|
echo "\nTest 3: Multi-Language Support\n";
|
|
echo "===============================\n";
|
|
|
|
// Test with different language configurations
|
|
$englishVector = $pdo->query("
|
|
SELECT to_tsvector('english', 'The cats are running quickly')::TEXT as vector
|
|
")->fetch(PDO::FETCH_ASSOC)['vector'];
|
|
echo "English stemming: {$englishVector}\n";
|
|
|
|
// German example (if available)
|
|
try {
|
|
$germanVector = $pdo->query("
|
|
SELECT to_tsvector('german', 'Die Katzen laufen schnell')::TEXT as vector
|
|
")->fetch(PDO::FETCH_ASSOC)['vector'];
|
|
echo "German stemming: {$germanVector}\n";
|
|
} catch (\PDOException $e) {
|
|
echo "German dictionary not available (this is optional)\n";
|
|
}
|
|
|
|
// Simple configuration (no stemming)
|
|
$simpleVector = $pdo->query("
|
|
SELECT to_tsvector('simple', 'The cats are running quickly')::TEXT as vector
|
|
")->fetch(PDO::FETCH_ASSOC)['vector'];
|
|
echo "Simple (no stemming): {$simpleVector}\n\n";
|
|
|
|
// Cleanup
|
|
echo "Cleaning up...\n";
|
|
$pdo->exec("DROP TABLE IF EXISTS test_articles");
|
|
$pdo->exec("DROP TABLE IF EXISTS test_products_fts");
|
|
echo "✅ Test tables dropped\n";
|
|
|
|
echo "\n✅ All Full-Text Search tests passed!\n";
|
|
echo "\nSummary:\n";
|
|
echo "========\n";
|
|
echo "✅ TSVECTOR column type works\n";
|
|
echo "✅ GIN indexes on TSVECTOR work\n";
|
|
echo "✅ to_tsvector() function works\n";
|
|
echo "✅ to_tsquery() boolean queries work (& | !)\n";
|
|
echo "✅ phraseto_tsquery() phrase search works\n";
|
|
echo "✅ ts_rank() ranking works\n";
|
|
echo "✅ ts_headline() highlighting works\n";
|
|
echo "✅ Generated TSVECTOR columns work\n";
|
|
echo "✅ Auto-update of generated columns works\n";
|
|
echo "✅ Multi-language support works\n";
|
|
|
|
} catch (\Exception $e) {
|
|
echo "❌ Error: " . $e->getMessage() . "\n";
|
|
echo "Stack trace:\n" . $e->getTraceAsString() . "\n";
|
|
exit(1);
|
|
}
|