From d8b0777a3b5d9cd4fa8bd5f420463b291e3c57c6 Mon Sep 17 00:00:00 2001 From: Nettika Date: Mon, 5 May 2025 13:47:08 -0700 Subject: [PATCH] Test indexed vs non-indexed datasets Improve benchmark UI Disable function and php tests (they are very slow) --- index.php | 266 ++++++++++++++++++++++++++++++++++++++---------------- readme.md | 15 +-- setup.sql | 87 +++++++++++++++++- 3 files changed, 280 insertions(+), 88 deletions(-) diff --git a/index.php b/index.php index c52c880..28fa5c5 100644 --- a/index.php +++ b/index.php @@ -11,110 +11,194 @@ $username = $_SERVER['PHP_AUTH_USER']; $password = $_SERVER['PHP_AUTH_PW']; $con = mysqli_connect("localhost", $username, $password, "test"); -print '

Total rows: ' . mysqli_num_rows(mysqli_query($con, "SELECT * FROM floats;")) . '

'; -print '

Selecting rows within 50 miles of Seattle...

'; +print ' + + + + +Haversine Query Benchmarks + + + +

Total rows: ' . mysqli_num_rows(mysqli_query($con, "SELECT * FROM floats;")) . '

+

Selecting rows within 50 miles of Seattle...

+ + + + + + + + + + +'; flush(); -print '
'; +test( + $con, + 'floats : procedure', + "CALL float_coords_within_radius(47.6, -122.33, 50);" // Within 50 miles of Seattle +); -$start = microtime(true); -$result = mysqli_query($con, "CALL float_coords_within_radius(47.6, -122.33, 50);"); // Within 50 miles of Seattle -$end = microtime(true); -print '
floats : procedure
'; -print '
Time taken: ' . ($end - $start) . '
'; -print '
Results: ' . mysqli_num_rows($result) . '
'; -mysqli_next_result($con); +test( + $con, + 'floats_indexed : procedure', + "CALL float_indexed_coords_within_radius(47.6, -122.33, 50);" // Within 50 miles of Seattle +); -flush(); +test( + $con, + 'floats : function', + "SELECT * FROM floats WHERE haversine(lat, lon, 47.6, -122.33) < 50;", // Within 50 miles of Seattle + false // disabled +); -$start = microtime(true); -$result = mysqli_query($con, "SELECT * FROM floats WHERE haversine(lat, lon, 47.6, -122.33) < 50;"); // Within 50 miles of Seattle -$end = microtime(true); -print '
floats : function
'; -print '
Time taken: ' . ($end - $start) . '
'; -print '
Results: ' . mysqli_num_rows($result) . '
'; -mysqli_next_result($con); +test( + $con, + 'floats : function alt', + "SELECT * FROM floats WHERE haversine_alt(lat, lon, 47.6, -122.33) < 50;", // Within 50 miles of Seattle + false // disabled +); -flush(); +test( + $con, + 'floats_indexed : function', + "SELECT * FROM floats_indexed WHERE haversine(lat, lon, 47.6, -122.33) < 50;", // Within 50 miles of Seattle + false // disabled +); -$start = microtime(true); -$result = mysqli_query($con, "SELECT * FROM floats WHERE haversine_alt(lat, lon, 47.6, -122.33) < 50;"); -$end = microtime(true); -print '
floats : function alt
'; -print '
Time taken: ' . ($end - $start) . '
'; -print '
Results: ' . mysqli_num_rows($result) . '
'; -mysqli_next_result($con); +test( + $con, + 'floats_indexed : function alt', + "SELECT * FROM floats_indexed WHERE haversine_alt(lat, lon, 47.6, -122.33) < 50;", // Within 50 miles of Seattle + false // disabled +); -flush(); - -$start = microtime(true); -$result = mysqli_query($con, "SELECT * FROM floats where acos( +test( + $con, + 'floats : inlined', + "SELECT * FROM floats WHERE acos( cos(radians(lat)) * cos(radians(47.6)) * cos(radians(lon) - radians(-122.33)) + sin(radians(lat)) * sin(radians(47.6)) -) * 3959 < 50;"); // Within 50 miles of Seattle -$end = microtime(true); -print '
floats : inlined
'; -print '
Time taken: ' . ($end - $start) . '
'; -print '
Results: ' . mysqli_num_rows($result) . '
'; +) * 3959 < 50;" // Within 50 miles of Seattle +); -flush(); +test( + $con, + 'floats_indexed : inlined', + "SELECT * FROM floats_indexed WHERE acos( + cos(radians(lat)) * + cos(radians(47.6)) * + cos(radians(lon) - radians(-122.33)) + + sin(radians(lat)) * + sin(radians(47.6)) +) * 3959 < 50;" // Within 50 miles of Seattle +); -$results = []; -$start = microtime(true); -$result = mysqli_query($con, "SELECT * FROM floats;"); -while ($row = mysqli_fetch_assoc($result)) { - if (haversine($row['lat'], $row['lon'], 47.6, -122.33) < 50) { // Within 50 miles of Seattle - $results[] = $row; - } +{ + // $results = []; + // $start = microtime(true); + // $result = mysqli_query($con, "SELECT * FROM floats;"); + // while ($row = mysqli_fetch_assoc($result)) { + // if (haversine($row['lat'], $row['lon'], 47.6, -122.33) < 50) { // Within 50 miles of Seattle + // $results[] = $row; + // } + // } + // $end = microtime(true); + // row('floats : php', $end - $start, 'SELECT * FROM floats;', count($results)); + row('floats : php', 'disabled', 'SELECT * FROM floats;', 0, true); // disabled } -$end = microtime(true); -print '
floats : php
'; -print '
Time taken: ' . ($end - $start) . '
'; -print '
Results: ' . count($results) . '
'; -flush(); +test( + $con, + 'hybrid : procedure', + 'CALL hybrid_coords_within_radius(47.6, -122.33, 80467);' // Within 80,467 meters (50 miles) of Seattle +); -$start = microtime(true); -$result = mysqli_query($con, "CALL hybrid_coords_within_radius(47.6, -122.33, 80467);"); // Within 80,467 meters (50 miles) of Seattle -$end = microtime(true); -print '
hybrid : procedure
'; -print '
Time taken: ' . ($end - $start) . '
'; -print '
Results: ' . mysqli_num_rows($result) . '
'; -mysqli_next_result($con); +test( + $con, + 'hybrid_point : procedure', + 'CALL hybrid_coords_within_radius_point(POINT(-122.33, 47.6), 80467);' // Within 80,467 meters (50 miles) of Seattle +); -flush(); +test( + $con, + 'hybrid_indexed : procedure', + 'CALL hybrid_indexed_coords_within_radius(47.6, -122.33, 80467);' // Within 80,467 meters (50 miles) of Seattle +); -$start = microtime(true); -$result = mysqli_query($con, "SELECT * FROM floats WHERE ST_DISTANCE_SPHERE(POINT(-122.33, 47.6), POINT(lon, lat)) < 80467;"); // Within 80,467 meters (50 miles) of Seattle -$end = microtime(true); -print '
hybrid : inlined
'; -print '
Time taken: ' . ($end - $start) . '
'; -print '
Results: ' . mysqli_num_rows($result) . '
'; +test( + $con, + 'hybrid_indexed_point : procedure', + 'CALL hybrid_indexed_coords_within_radius_point(POINT(-122.33, 47.6), 80467);' // Within 80,467 meters (50 miles) of Seattle +); -flush(); +test( + $con, + 'hybrid : inlined', + "SELECT * FROM floats WHERE ST_DISTANCE_SPHERE(POINT(-122.33, 47.6), POINT(lon, lat)) < 80467;", // Within 80,467 meters (50 miles) of Seattle +); -$start = microtime(true); -$result = mysqli_query($con, "CALL point_coords_within_radius(POINT(-122.33, 47.6), 80467);"); // Within 80,467 meters (50 miles) of Seattle -$end = microtime(true); -print '
points : procedure
'; -print '
Time taken: ' . ($end - $start) . '
'; -print '
Results: ' . mysqli_num_rows($result) . '
'; -mysqli_next_result($con); +test( + $con, + 'hybrid_indexed : inlined', + "SELECT * FROM floats_indexed WHERE ST_DISTANCE_SPHERE(POINT(-122.33, 47.6), POINT(lon, lat)) < 80467;" // Within 80,467 meters (50 miles) of Seattle +); -flush(); +test( + $con, + 'points : procedure', + "CALL point_coords_within_radius(POINT(-122.33, 47.6), 80467);" // Within 80,467 meters (50 miles) of Seattle +); -$start = microtime(true); -$result = mysqli_query($con, "SELECT * FROM points WHERE ST_DISTANCE_SPHERE(POINT(-122.33, 47.6), coord) < 80467;"); // Within 80,467 meters (50 miles) of Seattle -$end = microtime(true); -print '
points : inlined
'; -print '
Time taken: ' . ($end - $start) . '
'; -print '
Results: ' . mysqli_num_rows($result) . '
'; +test( + $con, + 'points_indexed : procedure', + "CALL point_indexed_coords_within_radius(POINT(-122.33, 47.6), 80467);" // Within 80,467 meters (50 miles) of Seattle +); -print '
'; +test( + $con, + 'points : inlined', + "SELECT * FROM points WHERE ST_DISTANCE_SPHERE(POINT(-122.33, 47.6), coord) < 80467;" // Within 80,467 meters (50 miles) of Seattle +); + +test( + $con, + 'points_indexed : inlined', + "SELECT * FROM points_indexed WHERE ST_DISTANCE_SPHERE(POINT(-122.33, 47.6), coord) < 80467;" // Within 80,467 meters (50 miles) of Seattle +); + +print ' +
TestTime takenQueryResults
+ + +'; function haversine($latFrom, $lonFrom, $latTo, $lonTo) { @@ -135,3 +219,29 @@ function haversine($latFrom, $lonFrom, $latTo, $lonTo) return 3959 * $chord; // as miles } +function test($con, $name, $query, $enabled = true) +{ + if (!$enabled) { + row($name, 'disabled', $query, 0, true); + return; + } + $start = microtime(true); + $result = mysqli_query($con, $query); + $end = microtime(true); + row($name, $end - $start, $query, mysqli_num_rows($result)); + try { + mysqli_next_result($con); + } catch (Exception $e) {} +} + +function row($name, $duration, $query, $results, $disabled = false) +{ + print ' + ' . htmlspecialchars($name) . ' + +
' . htmlspecialchars($query) . '
+ ' . $results . ' + +'; + flush(); +} \ No newline at end of file diff --git a/readme.md b/readme.md index ef722c8..bb35d8f 100644 --- a/readme.md +++ b/readme.md @@ -7,12 +7,15 @@ ``` This will (re)create: - - Two tables `floats` and `points`. - - Three procedures `generate_coords`, `float_coords_within_radius`, - `hybrid_coords_within_radius`, and `point_coords_within_radius`. - - Two functions `haversine` and `haversine_alt`. + - Four tables: `floats`, `floats_indexed`, `points`, and `points_indexed`. + - Nine procedures: `generate_coords`, `float_coords_within_radius`, + `float_indexed_coords_within_radius`, `hybrid_coords_within_radius` + `hybrid_coords_within_radius_point`, `hybrid_indexed_coords_within_radius`, + `hybrid_indexed_coords_within_radius_point`, `point_coords_within_radius`, + `point_indexed_coords_within_radius` + - Two functions: `haversine` and `haversine_alt`. - And then will generate and insert 1,000,000 random coordinates into `floats` and - `points`. + And then will generate and insert 1,000,000 random coordinates into each of + the four tables. 2. Navigate to `index.php` in your browser and login. diff --git a/setup.sql b/setup.sql index eae701c..1c15348 100644 --- a/setup.sql +++ b/setup.sql @@ -3,12 +3,31 @@ CREATE TABLE points (coord POINT NOT NULL) ENGINE=Aria; \! echo "Created 'points' table." +DROP TABLE IF EXISTS points_indexed; +CREATE TABLE points_indexed ( + coord POINT NOT NULL, + SPATIAL INDEX (coord), + INDEX (coord) +) ENGINE=Aria; + +\! echo "Created 'points_spatial' table." + DROP TABLE IF EXISTS floats; CREATE TABLE floats (lat FLOAT NOT NULL, lon FLOAT NOT NULL) ENGINE=Aria; -CREATE INDEX coord ON floats (lat, lon); \! echo "Created 'floats' table." +DROP TABLE IF EXISTS floats_indexed; +CREATE TABLE floats_indexed ( + lat FLOAT NOT NULL, + lon FLOAT NOT NULL, + INDEX (lat, lon), + INDEX (lat), + INDEX (lon) +) ENGINE=Aria; + +\! echo "Created 'floats_indexed' table." + DELIMITER $$ DROP PROCEDURE IF EXISTS generate_coords; @@ -20,8 +39,12 @@ BEGIN WHILE i < amount DO SET lat = rand() * 180 - 90; -- Random latitude between -90 and 90 SET lon = rand() * 360 - 180; -- Random longitude between -180 and 180 - INSERT INTO points (coord) VALUES (POINT(lon, lat)); - INSERT INTO floats (lat, lon) VALUES (lat, lon); + START TRANSACTION; + INSERT INTO points (coord) VALUES (POINT(lon, lat)); + INSERT INTO points_indexed (coord) VALUES (POINT(lon, lat)); + INSERT INTO floats (lat, lon) VALUES (lat, lon); + INSERT INTO floats_indexed (lat, lon) VALUES (lat, lon); + COMMIT; SET i = i + 1; END WHILE; END$$ @@ -44,6 +67,22 @@ END$$ \! echo "Created 'float_coords_within_radius' procedure." +DROP PROCEDURE IF EXISTS float_indexed_coords_within_radius; +CREATE PROCEDURE float_indexed_coords_within_radius(latTo FLOAT, lonTo FLOAT, radius_miles FLOAT) +BEGIN + SELECT * + FROM floats_indexed + WHERE acos( + cos(radians(lat)) * + cos(radians(latTo)) * + cos(radians(lon) - radians(lonTo)) + + sin(radians(lat)) * + sin(radians(latTo)) + ) * 3959 < radius_miles; +END$$ + +\! echo "Created 'float_indexed_coords_within_radius' procedure." + DROP PROCEDURE IF EXISTS hybrid_coords_within_radius; CREATE PROCEDURE hybrid_coords_within_radius(latTo FLOAT, lonTo FLOAT, radius_meters FLOAT) BEGIN @@ -54,6 +93,36 @@ END$$ \! echo "Created 'hybrid_coords_within_radius' procedure." +DROP PROCEDURE IF EXISTS hybrid_coords_within_radius_point; +CREATE PROCEDURE hybrid_coords_within_radius_point(target POINT, radius_meters FLOAT) +BEGIN + SELECT * + FROM floats + WHERE ST_DISTANCE_SPHERE(target, POINT(lon, lat)) < radius_meters; +END$$ + +\! echo "Created 'hybrid_coords_within_radius_point' procedure." + +DROP PROCEDURE IF EXISTS hybrid_indexed_coords_within_radius; +CREATE PROCEDURE hybrid_indexed_coords_within_radius(latTo FLOAT, lonTo FLOAT, radius_meters FLOAT) +BEGIN + SELECT * + FROM floats_indexed + WHERE ST_DISTANCE_SPHERE(POINT(lonTo, latTo), POINT(lon, lat)) < radius_meters; +END$$ + +\! echo "Created 'hybrid_coords_within_radius' procedure." + +DROP PROCEDURE IF EXISTS hybrid_indexed_coords_within_radius_point; +CREATE PROCEDURE hybrid_indexed_coords_within_radius_point(target POINT, radius_meters FLOAT) +BEGIN + SELECT * + FROM floats_indexed + WHERE ST_DISTANCE_SPHERE(target, POINT(lon, lat)) < radius_meters; +END$$ + +\! echo "Created 'hybrid_indexed_coords_within_radius_point' procedure." + DROP PROCEDURE IF EXISTS point_coords_within_radius; CREATE PROCEDURE point_coords_within_radius(target POINT, radius_meters FLOAT) BEGIN @@ -64,6 +133,16 @@ END$$ \! echo "Created 'point_coords_within_radius' procedure." +DROP PROCEDURE IF EXISTS point_indexed_coords_within_radius; +CREATE PROCEDURE point_indexed_coords_within_radius(target POINT, radius_meters FLOAT) +BEGIN + SELECT * + FROM points_indexed + WHERE ST_DISTANCE_SPHERE(target, coord) < radius_meters; +END$$ + +\! echo "Created 'point_indexed_coords_within_radius' procedure." + DROP FUNCTION IF EXISTS haversine; CREATE FUNCTION haversine(lat1 FLOAT, lon1 FLOAT, lat2 FLOAT, lon2 FLOAT) RETURNS FLOAT BEGIN @@ -102,5 +181,5 @@ DELIMITER ; CALL generate_coords(1000000); -- Generate 1 million random coordinates -\! echo "Inserted a million random coordinates into 'points' and 'floats'. Whew!" +\! echo "Inserted a million random coordinates into 'points', 'points_indexed', 'floats', and 'floats_indexed'. Whew!" \! echo "Benchmarks are ready to run."