先开启MySQL对自定义方法的支持:
set global log_bin_trust_function_creators=1;
版本一:
DELIMITER $$
CREATE DEFINER=`root`@`localhost` FUNCTION `getDistance`(
lng1 float(10,7)
,lat1 float(10,7)
,lng2 float(10,7)
,lat2 float(10,7)
) RETURNS double
begin
declare d double;
declare radius int;
set radius = 6378140; #假设地球为正球形,直径为6378140米
set d = (2*ATAN2(SQRT(SIN((lat1-lat2)*PI()/180/2)
*SIN((lat1-lat2)*PI()/180/2)+
COS(lat2*PI()/180)*COS(lat1*PI()/180)
*SIN((lng1-lng2)*PI()/180/2)
*SIN((lng1-lng2)*PI()/180/2)),
SQRT(1-SIN((lat1-lat2)*PI()/180/2)
*SIN((lat1-lat2)*PI()/180/2)
+COS(lat2*PI()/180)*COS(lat1*PI()/180)
*SIN((lng1-lng2)*PI()/180/2)
*SIN((lng1-lng2)*PI()/180/2))))*radius;
return d;
end
$$
DELIMITER ;
版本二:
DELIMITER $$
CREATE FUNCTION `haversine`(
lat1 FLOAT, lon1 FLOAT,
lat2 FLOAT, lon2 FLOAT
) RETURNS float
BEGIN
RETURN DEGREES(ACOS(
COS(RADIANS(lat1)) *
COS(RADIANS(lat2)) *
COS(RADIANS(lon2) - RADIANS(lon1)) +
SIN(RADIANS(lat1)) * SIN(RADIANS(lat2))
));
END
$$
DELIMITER;
版本三:
DELIMITER $$
CREATE DEFINER=`root`@`localhost` FUNCTION `FN_GET_DISTANCE`(
lat1 DOUBLE, lng1 DOUBLE, lat2 DOUBLE, lng2 DOUBLE
) RETURNS double
BEGIN
DECLARE radlat1 DOUBLE;
DECLARE radlat2 DOUBLE;
DECLARE theta DOUBLE;
DECLARE radtheta DOUBLE;
DECLARE dist DOUBLE;
SET radlat1 = PI() * lat1 / 180;
SET radlat2 = PI() * lat2 / 180;
SET theta = lng1 - lng2;
SET radtheta = PI() * theta / 180;
SET dist = sin(radlat1) * sin(radlat2) + cos(radlat1) * cos(radlat2) * cos(radtheta);
SET dist = acos(dist);
SET dist = dist * 180 / PI();
SET dist = dist * 60 * 1.1515;
SET dist = dist * 1.609344;
RETURN dist;
END$$
DELIMITER ;
后面个方案返回值的单位为度
转化成千米需要乘上6373
转化成米需要乘上6373000