106 lines
3.1 KiB
SQL
106 lines
3.1 KiB
SQL
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."
|