Test indexed vs non-indexed datasets

Improve benchmark UI

Disable function and php tests (they are very slow)
This commit is contained in:
2025-05-05 13:47:08 -07:00
parent e48fd1bd53
commit d8b0777a3b
3 changed files with 280 additions and 88 deletions

266
index.php
View File

@@ -11,110 +11,194 @@ $username = $_SERVER['PHP_AUTH_USER'];
$password = $_SERVER['PHP_AUTH_PW']; $password = $_SERVER['PHP_AUTH_PW'];
$con = mysqli_connect("localhost", $username, $password, "test"); $con = mysqli_connect("localhost", $username, $password, "test");
print '<p>Total rows: ' . mysqli_num_rows(mysqli_query($con, "SELECT * FROM floats;")) . '</p>'; print '<!DOCTYPE html>
print '<p>Selecting rows within 50 miles of Seattle...</p>'; <html lang="en">
<head>
<meta charset="UTF-8">
<meta name="viewport" content="width=device-width, initial-scale=1.0">
<title>Haversine Query Benchmarks</title>
<style>
table {
border-collapse: collapse;
thead {
background-color: #ddd;
}
tr.disabled {
background-color: #f2f2f2;
color: #999;
}
th, td {
border: 1px solid black;
padding: 0.8rem 1rem;
text-align: left;
pre {
margin: 0;
}
}
}
</style>
</head>
<body>
<p>Total rows: ' . mysqli_num_rows(mysqli_query($con, "SELECT * FROM floats;")) . '</p>
<p>Selecting rows within 50 miles of Seattle...</p>
<table>
<thead>
<tr>
<th>Test</th>
<th>Time taken</th>
<th>Query</th>
<th>Results</th>
</tr>
</thead>
<tbody>
';
flush(); flush();
print '<dl>'; test(
$con,
'floats : procedure',
"CALL float_coords_within_radius(47.6, -122.33, 50);" // Within 50 miles of Seattle
);
$start = microtime(true); test(
$result = mysqli_query($con, "CALL float_coords_within_radius(47.6, -122.33, 50);"); // Within 50 miles of Seattle $con,
$end = microtime(true); 'floats_indexed : procedure',
print '<dt>floats : procedure</dt>'; "CALL float_indexed_coords_within_radius(47.6, -122.33, 50);" // Within 50 miles of Seattle
print '<dd>Time taken: ' . ($end - $start) . '</dd>'; );
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
mysqli_next_result($con);
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); test(
$result = mysqli_query($con, "SELECT * FROM floats WHERE haversine(lat, lon, 47.6, -122.33) < 50;"); // Within 50 miles of Seattle $con,
$end = microtime(true); 'floats : function alt',
print '<dt>floats : function</dt>'; "SELECT * FROM floats WHERE haversine_alt(lat, lon, 47.6, -122.33) < 50;", // Within 50 miles of Seattle
print '<dd>Time taken: ' . ($end - $start) . '</dd>'; false // disabled
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>'; );
mysqli_next_result($con);
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); test(
$result = mysqli_query($con, "SELECT * FROM floats WHERE haversine_alt(lat, lon, 47.6, -122.33) < 50;"); $con,
$end = microtime(true); 'floats_indexed : function alt',
print '<dt>floats : function alt</dt>'; "SELECT * FROM floats_indexed WHERE haversine_alt(lat, lon, 47.6, -122.33) < 50;", // Within 50 miles of Seattle
print '<dd>Time taken: ' . ($end - $start) . '</dd>'; false // disabled
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>'; );
mysqli_next_result($con);
flush(); test(
$con,
$start = microtime(true); 'floats : inlined',
$result = mysqli_query($con, "SELECT * FROM floats where acos( "SELECT * FROM floats WHERE acos(
cos(radians(lat)) * cos(radians(lat)) *
cos(radians(47.6)) * cos(radians(47.6)) *
cos(radians(lon) - radians(-122.33)) + cos(radians(lon) - radians(-122.33)) +
sin(radians(lat)) * sin(radians(lat)) *
sin(radians(47.6)) sin(radians(47.6))
) * 3959 < 50;"); // Within 50 miles of Seattle ) * 3959 < 50;" // Within 50 miles of Seattle
$end = microtime(true); );
print '<dt>floats : inlined</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
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); // $results = [];
$result = mysqli_query($con, "SELECT * FROM floats;"); // $start = microtime(true);
while ($row = mysqli_fetch_assoc($result)) { // $result = mysqli_query($con, "SELECT * FROM floats;");
if (haversine($row['lat'], $row['lon'], 47.6, -122.33) < 50) { // Within 50 miles of Seattle // while ($row = mysqli_fetch_assoc($result)) {
$results[] = $row; // 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 '<dt>floats : php</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . count($results) . '</dd>';
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); test(
$result = mysqli_query($con, "CALL hybrid_coords_within_radius(47.6, -122.33, 80467);"); // Within 80,467 meters (50 miles) of Seattle $con,
$end = microtime(true); 'hybrid_point : procedure',
print '<dt>hybrid : procedure</dt>'; 'CALL hybrid_coords_within_radius_point(POINT(-122.33, 47.6), 80467);' // Within 80,467 meters (50 miles) of Seattle
print '<dd>Time taken: ' . ($end - $start) . '</dd>'; );
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
mysqli_next_result($con);
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); test(
$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 $con,
$end = microtime(true); 'hybrid_indexed_point : procedure',
print '<dt>hybrid : inlined</dt>'; 'CALL hybrid_indexed_coords_within_radius_point(POINT(-122.33, 47.6), 80467);' // Within 80,467 meters (50 miles) of Seattle
print '<dd>Time taken: ' . ($end - $start) . '</dd>'; );
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
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); test(
$result = mysqli_query($con, "CALL point_coords_within_radius(POINT(-122.33, 47.6), 80467);"); // Within 80,467 meters (50 miles) of Seattle $con,
$end = microtime(true); 'hybrid_indexed : inlined',
print '<dt>points : procedure</dt>'; "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
print '<dd>Time taken: ' . ($end - $start) . '</dd>'; );
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
mysqli_next_result($con);
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); test(
$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 $con,
$end = microtime(true); 'points_indexed : procedure',
print '<dt>points : inlined</dt>'; "CALL point_indexed_coords_within_radius(POINT(-122.33, 47.6), 80467);" // Within 80,467 meters (50 miles) of Seattle
print '<dd>Time taken: ' . ($end - $start) . '</dd>'; );
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
print '</dl>'; 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 '</tbody>
</table>
</body>
</html>
';
function haversine($latFrom, $lonFrom, $latTo, $lonTo) function haversine($latFrom, $lonFrom, $latTo, $lonTo)
{ {
@@ -135,3 +219,29 @@ function haversine($latFrom, $lonFrom, $latTo, $lonTo)
return 3959 * $chord; // as miles 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 '<tr' . ($disabled ? ' class="disabled"' : '') . '>
<td>' . htmlspecialchars($name) . '</td>
<td><time>' . $duration . '</time></td>
<td><pre>' . htmlspecialchars($query) . '</pre></td>
<td>' . $results . '</td>
</tr>
';
flush();
}

View File

@@ -7,12 +7,15 @@
``` ```
This will (re)create: This will (re)create:
- Two tables `floats` and `points`. - Four tables: `floats`, `floats_indexed`, `points`, and `points_indexed`.
- Three procedures `generate_coords`, `float_coords_within_radius`, - Nine procedures: `generate_coords`, `float_coords_within_radius`,
`hybrid_coords_within_radius`, and `point_coords_within_radius`. `float_indexed_coords_within_radius`, `hybrid_coords_within_radius`
- Two functions `haversine` and `haversine_alt`. `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 And then will generate and insert 1,000,000 random coordinates into each of
`points`. the four tables.
2. Navigate to `index.php` in your browser and login. 2. Navigate to `index.php` in your browser and login.

View File

@@ -3,12 +3,31 @@ CREATE TABLE points (coord POINT NOT NULL) ENGINE=Aria;
\! echo "Created 'points' table." \! 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; DROP TABLE IF EXISTS floats;
CREATE TABLE floats (lat FLOAT NOT NULL, lon FLOAT NOT NULL) ENGINE=Aria; CREATE TABLE floats (lat FLOAT NOT NULL, lon FLOAT NOT NULL) ENGINE=Aria;
CREATE INDEX coord ON floats (lat, lon);
\! echo "Created 'floats' table." \! 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 $$ DELIMITER $$
DROP PROCEDURE IF EXISTS generate_coords; DROP PROCEDURE IF EXISTS generate_coords;
@@ -20,8 +39,12 @@ BEGIN
WHILE i < amount DO WHILE i < amount DO
SET lat = rand() * 180 - 90; -- Random latitude between -90 and 90 SET lat = rand() * 180 - 90; -- Random latitude between -90 and 90
SET lon = rand() * 360 - 180; -- Random longitude between -180 and 180 SET lon = rand() * 360 - 180; -- Random longitude between -180 and 180
START TRANSACTION;
INSERT INTO points (coord) VALUES (POINT(lon, lat)); 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 (lat, lon) VALUES (lat, lon);
INSERT INTO floats_indexed (lat, lon) VALUES (lat, lon);
COMMIT;
SET i = i + 1; SET i = i + 1;
END WHILE; END WHILE;
END$$ END$$
@@ -44,6 +67,22 @@ END$$
\! echo "Created 'float_coords_within_radius' procedure." \! 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; DROP PROCEDURE IF EXISTS hybrid_coords_within_radius;
CREATE PROCEDURE hybrid_coords_within_radius(latTo FLOAT, lonTo FLOAT, radius_meters FLOAT) CREATE PROCEDURE hybrid_coords_within_radius(latTo FLOAT, lonTo FLOAT, radius_meters FLOAT)
BEGIN BEGIN
@@ -54,6 +93,36 @@ END$$
\! echo "Created 'hybrid_coords_within_radius' procedure." \! 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; DROP PROCEDURE IF EXISTS point_coords_within_radius;
CREATE PROCEDURE point_coords_within_radius(target POINT, radius_meters FLOAT) CREATE PROCEDURE point_coords_within_radius(target POINT, radius_meters FLOAT)
BEGIN BEGIN
@@ -64,6 +133,16 @@ END$$
\! echo "Created 'point_coords_within_radius' procedure." \! 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; DROP FUNCTION IF EXISTS haversine;
CREATE FUNCTION haversine(lat1 FLOAT, lon1 FLOAT, lat2 FLOAT, lon2 FLOAT) RETURNS FLOAT CREATE FUNCTION haversine(lat1 FLOAT, lon1 FLOAT, lat2 FLOAT, lon2 FLOAT) RETURNS FLOAT
BEGIN BEGIN
@@ -102,5 +181,5 @@ DELIMITER ;
CALL generate_coords(1000000); -- Generate 1 million random coordinates 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." \! echo "Benchmarks are ready to run."