Initial commit

This commit is contained in:
2025-04-25 13:19:27 -07:00
commit e48fd1bd53
3 changed files with 261 additions and 0 deletions

137
index.php Normal file
View File

@@ -0,0 +1,137 @@
<?php
if (!isset($_SERVER['PHP_AUTH_USER']) || !isset($_SERVER['PHP_AUTH_PW'])) {
header('HTTP/1.0 401 Unauthorized');
header('WWW-Authenticate: Basic realm="Database access"');
echo 'Unauthorized access. Please provide valid credentials.';
exit;
}
$username = $_SERVER['PHP_AUTH_USER'];
$password = $_SERVER['PHP_AUTH_PW'];
$con = mysqli_connect("localhost", $username, $password, "test");
print '<p>Total rows: ' . mysqli_num_rows(mysqli_query($con, "SELECT * FROM floats;")) . '</p>';
print '<p>Selecting rows within 50 miles of Seattle...</p>';
flush();
print '<dl>';
$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 '<dt>floats : procedure</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
mysqli_next_result($con);
flush();
$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 '<dt>floats : function</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
mysqli_next_result($con);
flush();
$start = microtime(true);
$result = mysqli_query($con, "SELECT * FROM floats WHERE haversine_alt(lat, lon, 47.6, -122.33) < 50;");
$end = microtime(true);
print '<dt>floats : function alt</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
mysqli_next_result($con);
flush();
$start = microtime(true);
$result = mysqli_query($con, "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 '<dt>floats : inlined</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
flush();
$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);
print '<dt>floats : php</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . count($results) . '</dd>';
flush();
$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 '<dt>hybrid : procedure</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
mysqli_next_result($con);
flush();
$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 '<dt>hybrid : inlined</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
flush();
$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 '<dt>points : procedure</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
mysqli_next_result($con);
flush();
$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 '<dt>points : inlined</dt>';
print '<dd>Time taken: ' . ($end - $start) . '</dd>';
print '<dd>Results: ' . mysqli_num_rows($result) . '</dd>';
print '</dl>';
function haversine($latFrom, $lonFrom, $latTo, $lonTo)
{
// convert from degrees to radians
$latFrom = deg2rad($latFrom);
$lonFrom = deg2rad($lonFrom);
$latTo = deg2rad($latTo);
$lonTo = deg2rad($lonTo);
$latDelta = $latTo - $latFrom;
$lonDelta = $lonTo - $lonFrom;
$angle = sin($latDelta / 2) * sin($latDelta / 2) +
cos($latFrom) * cos($latTo) *
sin($lonDelta / 2) * sin($lonDelta / 2);
$chord = 2 * atan2(sqrt($angle), sqrt(1 - $angle));
return 3959 * $chord; // as miles
}

18
readme.md Normal file
View File

@@ -0,0 +1,18 @@
# MySQL Haversine Benchmark
1. Run setup
```sh
mysql your-database-name < setup.sql
```
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`.
And then will generate and insert 1,000,000 random coordinates into `floats` and
`points`.
2. Navigate to `index.php` in your browser and login.

106
setup.sql Normal file
View File

@@ -0,0 +1,106 @@
DROP TABLE IF EXISTS points;
CREATE TABLE points (coord POINT NOT NULL) ENGINE=Aria;
\! echo "Created 'points' 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."
DELIMITER $$
DROP PROCEDURE IF EXISTS generate_coords;
CREATE PROCEDURE generate_coords(amount INT)
BEGIN
DECLARE i INT DEFAULT 0;
DECLARE lat FLOAT;
DECLARE lon FLOAT;
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);
SET i = i + 1;
END WHILE;
END$$
\! echo "Created 'generate_coords' procedure."
DROP PROCEDURE IF EXISTS float_coords_within_radius;
CREATE PROCEDURE float_coords_within_radius(latTo FLOAT, lonTo FLOAT, radius_miles FLOAT)
BEGIN
SELECT *
FROM floats
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_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
SELECT *
FROM floats
WHERE ST_DISTANCE_SPHERE(POINT(lonTo, latTo), POINT(lon, lat)) < radius_meters;
END$$
\! echo "Created 'hybrid_coords_within_radius' procedure."
DROP PROCEDURE IF EXISTS point_coords_within_radius;
CREATE PROCEDURE point_coords_within_radius(target POINT, radius_meters FLOAT)
BEGIN
SELECT *
FROM points
WHERE ST_DISTANCE_SPHERE(target, coord) < radius_meters;
END$$
\! echo "Created 'point_coords_within_radius' procedure."
DROP FUNCTION IF EXISTS haversine;
CREATE FUNCTION haversine(lat1 FLOAT, lon1 FLOAT, lat2 FLOAT, lon2 FLOAT) RETURNS FLOAT
BEGIN
RETURN acos(
cos(radians(lat1)) *
cos(radians(lat2)) *
cos(radians(lon1) - radians(lon2)) +
sin(radians(lat1)) *
sin(radians(lat2))
) * 3959; -- As miles
END$$
\! echo "Created 'haversine' function."
DROP FUNCTION IF EXISTS haversine_alt;
CREATE FUNCTION haversine_alt(lat1 FLOAT, lon1 FLOAT, lat2 FLOAT, lon2 FLOAT) RETURNS FLOAT
BEGIN
DECLARE deltaLat FLOAT;
DECLARE deltaLon FLOAT;
DECLARE angle FLOAT;
DECLARE chord FLOAT;
SET deltaLat = radians(lat2 - lat1);
SET deltaLon = radians(lon2 - lon1);
SET angle = sin(deltaLat / 2) * sin(deltaLat / 2) +
cos(radians(lat1)) * cos(radians(lat2)) *
sin(deltaLon / 2) * sin(deltaLon / 2);
SET chord = 2 * atan2(sqrt(angle), sqrt(1 - angle));
RETURN 3959 * chord; -- As miles
END$$
\! echo "Created 'haversine_alt' function."
DELIMITER ;
\! echo "Generating a million random coordinates. This may take a while..."
CALL generate_coords(1000000); -- Generate 1 million random coordinates
\! echo "Inserted a million random coordinates into 'points' and 'floats'. Whew!"
\! echo "Benchmarks are ready to run."