个人记载 方便查找
创建自增ID
CREATE SEQUENCE upms_log_id_seq START 10;
获取当前时间(精确到时分秒):
select to_char((select now()),'yyyy-mm-dd hh24:mm:ss')::timestamp
获取今天、昨天、上周一、上周日、本周一、本月、上月、今年、去年时间:
--今天
select to_char(current_date,'yyyy-MM-dd')::timestamp
--昨天
select to_char(current_date-1,'yyyy-MM-dd')::timestamp
--获取上周一时间 00:00:00
SELECT CURRENT_DATE - ( EXTRACT ( dow FROM CURRENT_DATE ) - 1 || ' day' ) :: INTERVAL - INTERVAL '7 day'
--获取上周日时间 23:59:59
SELECT CURRENT_DATE - ( EXTRACT ( dow FROM CURRENT_DATE ) - 1 || ' day' ) :: INTERVAL - INTERVAL '1 s'
--获取本周一时间 00:00:00
SELECT CURRENT_DATE - ( EXTRACT ( dow FROM CURRENT_DATE ) - 1 || ' day' ) :: INTERVAL
--本月
select to_char(current_date,'yyyy-MM')::timestamp
--上月
select to_char((select now() - interval '1 month'),'yyyy-mm')::timestamp
--本年
select to_char((select now() ),'yyyy')::timestamp
--去年
select to_char((select now() - interval '1 years'),'yyyy')::timestamp
查询指定时间字段今天、昨天、本月、上月、今年、去年表数据:
--今天
SELECT *
FROM
表名 AS n
WHERE
to_char( n.时间字段名, 'yyyy-mm-dd' ) = to_char( CURRENT_DATE, 'yyyy-MM-dd' );
--昨天
SELECT *
FROM
表名 AS n
WHERE
to_char( n.时间字段名, 'yyyy-MM-dd' ) = to_char( CURRENT_DATE - 1, 'yyyy-MM-dd' );
--本月
SELECT *
FROM
表名 AS n
WHERE
to_char( n.时间字段名, 'yyyy-mm' ) = to_char( ( SELECT now( ) AS TIMESTAMP ), 'yyyy-mm' );
--上月
SELECT *
FROM
表名 AS n
WHERE
to_char( n.时间字段名, 'yyyy-mm' ) = to_char( ( SELECT now( ) - INTERVAL '1 month' ), 'yyyy-mm' );
--本年
SELECT *
FROM
表名 AS n
WHERE
to_char( n.时间字段名, 'yyyy' ) = to_char( ( SELECT now( ) ), 'yyyy' );
--去年
SELECT *
FROM
表名 AS n
WHERE
to_char( n.时间字段名, 'yyyy' ) = to_char( ( SELECT now( ) - INTERVAL '1 years' ), 'yyyy' );
查询上周、上季度的数据:
--查询上周数据
SELECT *
FROM 表名
WHERE
时间字段名 BETWEEN
current_timestamp - (extract (dow from current_timestamp) - 1 || ' day')::interval - interval '7 day'
AND
current_timestamp - (extract (dow from current_timestamp) - 1 || ' day')::interval - interval '1 day'
--查询上季度数据
SELECT *
FROM 表名
WHERE
时间字段名 BETWEEN
date_trunc('quarter',now() + interval '-3 month')
AND
date_trunc('quarter',now() + interval '-3 month') + interval '3 month'
按照天、月、年求和:
--按天求和
SELECT
to_char( 时间字段, 'YYYY-mm-dd' ) AS time, SUM ( 求和字段 )
FROM
表名
GROUP BY time
--按月求和
SELECT
to_char( 时间字段, 'YYYY-mm' ) AS time, SUM ( 求和字段 )
FROM
表名
GROUP BY time
--按年求和
SELECT
to_char( 时间字段, 'YYYY' ) AS time, SUM ( 求和字段 )
FROM
表名
GROUP BY time
查询字段为空,赋默认值0:
COALESCE(字段名,0)
查询为null和不为null数据:
--查询某字段为空的数据
SELECT *
FROM 表名
WHERE 字段名 IS NULL
--查询某字段不为空的数据
SELECT *
FROM 表名
WHERE 字段名 IS NOT NULL
空间数据库相关
添加空间扩展
CREATE EXTENSION postgis;
CREATE EXTENSION pgrouting;
CREATE EXTENSION postgis_topology;
CREATE EXTENSION fuzzystrmatch;
CREATE EXTENSION postgis_tiger_geocoder;
CREATE EXTENSION address_standardizer;
postGIS的SRID更新
select UpdateGeometrySRID('表名', 'geom', 4326);
--查询SRID
select st_srid(geom) from table;
--坐标系转换 4326转3857
UPDATE colliery SET geom = ST_Transform ( st_geometryfromtext ( ST_AsText ( geom ), 4326 ), 3857 );
postgis火星坐标系转换
示例:
--GCJ02转WGS84
select geoc_gcj02towgs84(geom) from test_table
--WGS84转GCJ02
select geoc_wgs84togcj02(geom) from test_table
--WGS84转BD09
select geoc_wgs84tobd09(geom) from test_table
--BD09转WGS84
select geoc_bd09towgs84(geom) from test_table
--GCJ02转BD09
select geoc_gcj02tobd09(geom) from test_table
--BD09转GCJ02
select geoc_bd09togcj02(geom) from test_table
sql代码:
CREATE OR REPLACE FUNCTION "public"."geoc_bd09towgs84_multipolygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
single_polygon geometry;
single_polygon_trans geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_MultiPolygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT (ST_Dump($1)).geom LOOP
single_polygon_trans := geoc_bd09towgs84_polygon(single_polygon);
target_parts := array_append(target_parts,single_polygon_trans);
END LOOP;
SELECT st_multi(ST_Union(target_parts)) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09towgs84_point"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
x numeric;
y numeric;
gcj_point geometry;
wgs_point geometry;
BEGIN
if st_geometrytype(geom) != 'ST_Point' then
return null;
end if;
x := st_x(geom);
y := st_y(geom);
if (geoc_is_in_china_bbox(x, y) = false) then
return geom;
end if;
gcj_point = geoc_bd09togcj02_point(geom);
wgs_point = geoc_gcj02towgs84_point(gcj_point);
return wgs_point;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09towgs84_polygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
source_npoints integer;
single_line geometry;
single_line_trans geometry;
single_polygon geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_Polygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT ST_ExteriorRing ((st_dumprings($1)).geom) as geom LOOP
source_npoints := ST_NPoints(single_polygon);
single_line := ST_RemovePoint(single_polygon, source_npoints - 1);
single_line_trans := geoc_bd09towgs84_line(single_line);
target_parts := array_append(target_parts, ST_AddPoint(single_line_trans, ST_PointN(single_line_trans, 1)));
END LOOP;
SELECT ST_MakePolygon(target_parts[1], target_parts[2:array_upper(target_parts, 1)]) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_cgcs2000tobd09"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
BEGIN
IF st_srid(geom) != '4490' THEN
RETURN null;
end if;
return geoc_wgs84tobd09(st_transform(st_setsrid(geom,4490),4326));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_cgcs2000togcj02"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
BEGIN
IF st_srid(geom) != '4490' THEN
RETURN null;
end if;
return geoc_wgs84togcj02(st_transform(st_setsrid(geom,4490),4326));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_delta"("lon" numeric, "lat" numeric)
RETURNS "pg_catalog"."jsonb" AS $BODY$
DECLARE
ret varchar;
dLon numeric;
dlat numeric;
radLat numeric;
magic numeric;
sqrtMagic numeric;
ee numeric;
a numeric;
BEGIN
ee := 0.006693421622965823;
a := 6378245;
dLon := geoc_transform_lon(lon - 105, lat - 35);
dLat := geoc_transform_lat(lon - 105, lat - 35);
radLat := lat / 180 * pi();
magic = sin(radLat);
magic = 1 - ee * magic * magic;
sqrtMagic := sqrt(magic);
dLon = (dLon * 180) / (a / sqrtMagic * cos(radLat) * pi());
dLat = (dLat * 180) / ((a * (1 - ee)) / (magic * sqrtMagic) * pi());
ret :='['||dLon||','||dLat||']';
return ret::jsonb;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02tobd09"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
BEGIN
IF st_srid(geom) != '4490' and st_srid(geom) != '4326'THEN
RETURN null;
end if;
case ST_GeometryType(geom)
when 'ST_LineString' then
return geoc_gcj02tobd09_line(geom);
when 'ST_MultiLineString' then
return geoc_gcj02tobd09_multiline(geom);
when 'ST_Point' then
return geoc_gcj02tobd09_point(geom);
when 'ST_MultiPoint' then
return geoc_gcj02tobd09_multipoint(geom);
when 'ST_Polygon' then
return geoc_gcj02tobd09_polygon(geom);
when 'ST_MultiPolygon' then
return geoc_gcj02tobd09_multipolygon(geom);
ELSE
RETURN null;
END CASE;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02tobd09_line"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
p_p geometry;
p_t geometry;
z_t geometry;
i int;
BEGIN
i:=1;
while i <= st_npoints(geom) LOOP
p_p := st_pointn(geom,i);
p_t := geoc_gcj02tobd09_point(p_p);
geom:=st_setpoint(geom,i-1,p_t);
i:=i+1;
end LOOP;
return geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02tobd09_multiline"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_gcj02tobd09_line(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02tobd09_multipoint"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_gcj02tobd09_point(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02tobd09_multipolygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
single_polygon geometry;
single_polygon_trans geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_MultiPolygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT (ST_Dump($1)).geom LOOP
single_polygon_trans := geoc_gcj02tobd09_polygon(single_polygon);
target_parts := array_append(target_parts,single_polygon_trans);
END LOOP;
SELECT st_multi(ST_Union(target_parts)) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02tobd09_point"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
z double precision;
theta double precision;
x_pi double precision:=3.14159265358979324 * 3000.0 / 180.0;
lon numeric;
lat numeric;
bd_point geometry;
BEGIN
if st_geometrytype(geom) != 'ST_Point' then
return null;
end if;
lon := st_x(geom);
lat := st_y(geom);
if geoc_is_in_china_bbox(lon, lat) = false THEN
return geom;
end if;
z:= sqrt(power(lon,2) + power(lat,2)) + 0.00002 * sin(lat * x_pi);
theta:= atan2(lat, lon) + 0.000003 * cos(lon * x_pi);
bd_point:=ST_SetSRID(ST_MakePoint(z * cos(theta) + 0.0065,z * sin(theta) + 0.006),4326);
return bd_point;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02tobd09_polygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
source_npoints integer;
single_line geometry;
single_line_trans geometry;
single_polygon geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_Polygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT ST_ExteriorRing ((st_dumprings($1)).geom) as geom LOOP
source_npoints := ST_NPoints(single_polygon);
single_line := ST_RemovePoint(single_polygon, source_npoints - 1);
single_line_trans := geoc_gcj02tobd09_line(single_line);
target_parts := array_append(target_parts, ST_AddPoint(single_line_trans, ST_PointN(single_line_trans, 1)));
END LOOP;
SELECT ST_MakePolygon(target_parts[1], target_parts[2:array_upper(target_parts, 1)]) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02tocgcs2000"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
BEGIN
IF st_srid(geom) != '4490' THEN
RETURN null;
end if;
return st_transform(st_setsrid(geoc_gcj02towgs84(geom),4326),4490);
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02towgs84"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
BEGIN
IF st_srid(geom) != '4490' and st_srid(geom) != '4326'THEN
RETURN null;
end if;
case ST_GeometryType(geom)
when 'ST_LineString' then
return geoc_gcj02towgs84_line(geom);
when 'ST_MultiLineString' then
return geoc_gcj02towgs84_multiline(geom);
when 'ST_Point' then
return geoc_gcj02towgs84_point(geom);
when 'ST_MultiPoint' then
return geoc_gcj02towgs84_multipoint(geom);
when 'ST_Polygon' then
return geoc_gcj02towgs84_polygon(geom);
when 'ST_MultiPolygon' then
return geoc_gcj02towgs84_multipolygon(geom);
ELSE
RETURN null;
END CASE;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02towgs84_line"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
p_p geometry;
p_t geometry;
z_t geometry;
i int;
BEGIN
i:=1;
while i <= st_npoints(geom) LOOP
p_p := st_pointn(geom,i);
p_t := geoc_gcj02towgs84_point(p_p);
geom:=st_setpoint(geom,i-1,p_t);
i:=i+1;
end LOOP;
return geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02towgs84_multiline"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_gcj02towgs84_line(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02towgs84_multipoint"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_gcj02towgs84_point(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02towgs84_multipolygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
single_polygon geometry;
single_polygon_trans geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_MultiPolygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT (ST_Dump($1)).geom LOOP
single_polygon_trans := geoc_gcj02towgs84_polygon(single_polygon);
target_parts := array_append(target_parts,single_polygon_trans);
END LOOP;
SELECT st_multi(ST_Union(target_parts)) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02towgs84_point"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
tempPoint numeric[];
wgsLon numeric;
wgsLat numeric;
lon numeric;
lat numeric;
BEGIN
if st_geometrytype(geom) != 'ST_Point' then
return null;
end if;
lon := st_x(geom);
lat := st_y(geom);
if geoc_is_in_china_bbox(lon, lat) = false THEN
return geom;
end if;
tempPoint := geoc_wgs84togcj02(ARRAY[lon, lat]);
wgsLon := lon*2 - tempPoint[1];
wgsLat := lat*2 - tempPoint[2];
return st_makepoint(wgsLon,wgsLat);
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_gcj02towgs84_polygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
source_npoints integer;
single_line geometry;
single_line_trans geometry;
single_polygon geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_Polygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT ST_ExteriorRing ((st_dumprings($1)).geom) as geom LOOP
source_npoints := ST_NPoints(single_polygon);
single_line := ST_RemovePoint(single_polygon, source_npoints - 1);
single_line_trans := geoc_gcj02towgs84_line(single_line);
target_parts := array_append(target_parts, ST_AddPoint(single_line_trans, ST_PointN(single_line_trans, 1)));
END LOOP;
SELECT ST_MakePolygon(target_parts[1], target_parts[2:array_upper(target_parts, 1)]) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_is_in_china_bbox"("lon" numeric, "lat" numeric)
RETURNS "pg_catalog"."bool" AS $BODY$
DECLARE
BEGIN
return lon >= 72.004 and lon <= 137.8347 and lat >= 0.8293 and lat <= 55.8271;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_transform_lat"("x" numeric, "y" numeric)
RETURNS "pg_catalog"."numeric" AS $BODY$
DECLARE
ret numeric;
BEGIN
ret := -100 + 2 * x + 3 * y + 0.2 * y * y + 0.1 * x * y + 0.2 * sqrt(abs(x));
ret := ret + (20 * sin(6 * x * PI()) + 20 * sin(2 * x * PI())) * 2 / 3;
ret := ret +(20 * sin(y * PI()) + 40 * sin(y / 3 * PI())) * 2 / 3;
ret := ret +(160 * sin(y / 12 * PI()) + 320 * sin(y * PI() / 30)) * 2 / 3;
return ret;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_transform_lon"("x" numeric, "y" numeric)
RETURNS "pg_catalog"."numeric" AS $BODY$
DECLARE
ret numeric;
BEGIN
ret := 300 + x + 2 * y + 0.1 * x * x + 0.1 * x * y + 0.1 * sqrt(abs(x));
ret :=ret + (20 * sin(6 * x * pi()) + 20 * sin(2 * x * pi())) * 2 / 3;
ret :=ret + (20 * sin(x * pi()) + 40 * sin(x / 3 * pi())) * 2 / 3;
ret :=ret + (150 * sin(x / 12 * pi()) + 300 * sin(x / 30 * pi())) * 2 / 3;
return ret;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84tobd09"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
BEGIN
IF st_srid(geom) != '4490' and st_srid(geom) != '4326'THEN
RETURN null;
end if;
case ST_GeometryType(geom)
when 'ST_LineString' then
return geoc_wgs84tobd09_line(geom);
when 'ST_MultiLineString' then
return geoc_wgs84tobd09_multiline(geom);
when 'ST_Point' then
return geoc_wgs84tobd09_point(geom);
when 'ST_MultiPoint' then
return geoc_wgs84tobd09_multipoint(geom);
when 'ST_Polygon' then
return geoc_wgs84tobd09_polygon(geom);
when 'ST_MultiPolygon' then
return geoc_wgs84tobd09_multipolygon(geom);
ELSE
RETURN null;
END CASE;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84tobd09_line"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
p_p geometry;
p_t geometry;
z_t geometry;
i int;
BEGIN
i:=1;
while i <= st_npoints(geom) LOOP
p_p := st_pointn(geom,i);
p_t := geoc_wgs84tobd09_point(p_p);
geom:=st_setpoint(geom,i-1,p_t);
i:=i+1;
end LOOP;
return geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84tobd09_multiline"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_wgs84tobd09_line(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84tobd09_multipoint"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_wgs84tobd09_point(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84tobd09_multipolygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
single_polygon geometry;
single_polygon_trans geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_MultiPolygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT (ST_Dump($1)).geom LOOP
single_polygon_trans := geoc_wgs84tobd09_polygon(single_polygon);
target_parts := array_append(target_parts,single_polygon_trans);
END LOOP;
SELECT st_multi(ST_Union(target_parts)) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84tobd09_point"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
lon numeric;
lat numeric;
bd_point geometry;
gcj_point geometry;
BEGIN
if st_geometrytype(geom) != 'ST_Point' then
return null;
end if;
lon := st_x(geom);
lat := st_y(geom);
if geoc_is_in_china_bbox(lon, lat) = false THEN
return geom;
end if;
gcj_point = geoc_wgs84togcj02_point(geom);
bd_point = geoc_gcj02tobd09_point(gcj_point);
return bd_point;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84tobd09_polygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
source_npoints integer;
single_line geometry;
single_line_trans geometry;
single_polygon geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_Polygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT ST_ExteriorRing ((st_dumprings($1)).geom) as geom LOOP
source_npoints := ST_NPoints(single_polygon);
single_line := ST_RemovePoint(single_polygon, source_npoints - 1);
single_line_trans := geoc_wgs84tobd09_line(single_line);
target_parts := array_append(target_parts, ST_AddPoint(single_line_trans, ST_PointN(single_line_trans, 1)));
END LOOP;
SELECT ST_MakePolygon(target_parts[1], target_parts[2:array_upper(target_parts, 1)]) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84togcj02"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
IF st_srid(geom) != '4490' and st_srid(geom) != '4326'THEN
RETURN null;
end if;
CASE ST_GeometryType(geom)
when 'ST_LineString' then
return geoc_wgs84togcj02_line(geom);
when 'ST_MultiLineString' then
return geoc_wgs84togcj02_multiline(geom);
when 'ST_Point' then
return geoc_wgs84togcj02_point(geom);
when 'ST_MultiPoint' then
return geoc_wgs84togcj02_multipoint(geom);
when 'ST_Polygon' then
return geoc_wgs84togcj02_polygon(geom);
when 'ST_MultiPolygon' then
return geoc_wgs84togcj02_multipolygon(geom);
ELSE
RETURN null;
END CASE;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84togcj02_line"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
p_p geometry;
p_t geometry;
z_t geometry;
i int;
BEGIN
i:=1;
while i <= st_npoints(geom) LOOP
p_p := st_pointn(geom,i);
p_t := geoc_wgs84togcj02_point(p_p);
geom:=st_setpoint(geom,i-1,p_t);
i:=i+1;
end LOOP;
return geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84togcj02_multiline"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_wgs84togcj02_line(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84togcj02_multipoint"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_wgs84togcj02_point(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84togcj02_multipolygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
single_polygon geometry;
single_polygon_trans geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_MultiPolygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT (ST_Dump($1)).geom LOOP
single_polygon_trans := geoc_wgs84togcj02_polygon(single_polygon);
target_parts := array_append(target_parts,single_polygon_trans);
END LOOP;
SELECT st_multi(ST_Union(target_parts)) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84togcj02"("coord" _numeric)
RETURNS "pg_catalog"."_numeric" AS $BODY$
DECLARE
ret numeric[];
dLon numeric;
dlat numeric;
lon numeric;
lat numeric;
d jsonb;
-- coord ARRAY;
BEGIN
lon := coord[1];
lat := coord[2];
if (geoc_is_in_china_bbox(lon, lat) = false) then
return coord;
end if;
d := geoc_delta(lon, lat);
dlon := d->0;
dlat := d->1;
ret := ARRAY[lon + dlon , lat + dlat];
return ret;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84togcj02_point"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
lon numeric;
lat numeric;
d jsonb;
dlon numeric;
dlat numeric;
BEGIN
if st_geometrytype(geom) != 'ST_Point' then
return null;
end if;
lon := st_x(geom);
lat := st_y(geom);
if (geoc_is_in_china_bbox(lon, lat) = false) then
return geom;
end if;
d := geoc_delta(lon, lat);
dlon := d->0;
dlat := d->1;
return st_makepoint(lon + dlon,lat + dlat);
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_wgs84togcj02_polygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
source_npoints integer;
single_line geometry;
single_line_trans geometry;
single_polygon geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_Polygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT ST_ExteriorRing ((st_dumprings($1)).geom) as geom LOOP
source_npoints := ST_NPoints(single_polygon);
single_line := ST_RemovePoint(single_polygon, source_npoints - 1);
single_line_trans := geoc_wgs84togcj02_line(single_line);
target_parts := array_append(target_parts, ST_AddPoint(single_line_trans, ST_PointN(single_line_trans, 1)));
END LOOP;
SELECT ST_MakePolygon(target_parts[1], target_parts[2:array_upper(target_parts, 1)]) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09tocgcs2000"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
BEGIN
IF st_srid(geom) != '4490' THEN
RETURN null;
end if;
return st_transform(st_setsrid(geoc_bd09towgs84(geom),4326),4490);
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09togcj02"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
IF st_srid(geom) != '4490' and st_srid(geom) != '4326'THEN
RETURN null;
end if;
CASE ST_GeometryType(geom)
when 'ST_LineString' then
return geoc_bd09togcj02_line(geom);
when 'ST_MultiLineString' then
return geoc_bd09togcj02_multiline(geom);
when 'ST_Point' then
return geoc_bd09togcj02_point(geom);
when 'ST_MultiPoint' then
return geoc_bd09togcj02_multipoint(geom);
when 'ST_Polygon' then
return geoc_bd09togcj02_polygon(geom);
when 'ST_MultiPolygon' then
return geoc_bd09togcj02_multipolygon(geom);
ELSE
RETURN null;
END CASE;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09togcj02_line"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
p_p geometry;
p_t geometry;
z_t geometry;
i int;
BEGIN
i:=1;
while i <= st_npoints(geom) LOOP
p_p := st_pointn(geom,i);
p_t := geoc_bd09togcj02_point(p_p);
geom:=st_setpoint(geom,i-1,p_t);
i:=i+1;
end LOOP;
return geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09togcj02_multiline"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_bd09togcj02_line(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09togcj02_multipoint"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_bd09togcj02_point(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09togcj02_multipolygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
single_polygon geometry;
single_polygon_trans geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_MultiPolygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT (ST_Dump($1)).geom LOOP
single_polygon_trans := geoc_bd09togcj02_polygon(single_polygon);
target_parts := array_append(target_parts,single_polygon_trans);
END LOOP;
SELECT st_multi(ST_Union(target_parts)) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09togcj02_point"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
x numeric;
y numeric;
z double precision;
theta double precision;
x_pi double precision:=3.14159265358979324 * 3000.0 / 180.0;
gcj_point geometry;
BEGIN
if st_geometrytype(geom) != 'ST_Point' then
return null;
end if;
x := st_x(geom);
y := st_y(geom);
if (geoc_is_in_china_bbox(x, y) = false) then
return geom;
end if;
x:= ST_X(geom) - 0.0065;
y:= ST_Y(geom) - 0.006;
z:=sqrt(power(x,2) + power(y,2)) - 0.00002 *sin(y * x_pi);
theta:= atan2(y, x) - 0.000003 * cos(x * x_pi);
gcj_point:=ST_SetSRID(ST_MakePoint(z *cos(theta),z *sin(theta)),4326);
return gcj_point;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09togcj02_polygon"("source_geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
target_parts geometry[];
source_npoints integer;
single_line geometry;
single_line_trans geometry;
single_polygon geometry;
final_geom geometry;
BEGIN
IF ST_GeometryType(source_geom) != 'ST_Polygon' THEN
RETURN null;
END IF;
FOR single_polygon IN SELECT ST_ExteriorRing ((st_dumprings($1)).geom) as geom LOOP
source_npoints := ST_NPoints(single_polygon);
single_line := ST_RemovePoint(single_polygon, source_npoints - 1);
single_line_trans := geoc_bd09togcj02_line(single_line);
target_parts := array_append(target_parts, ST_AddPoint(single_line_trans, ST_PointN(single_line_trans, 1)));
END LOOP;
SELECT ST_MakePolygon(target_parts[1], target_parts[2:array_upper(target_parts, 1)]) INTO final_geom;
RETURN final_geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09towgs84"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
IF st_srid(geom) != '4490' and st_srid(geom) != '4326'THEN
RETURN null;
end if;
CASE ST_GeometryType(geom)
when 'ST_LineString' then
return geoc_bd09towgs84_line(geom);
when 'ST_MultiLineString' then
return geoc_bd09towgs84_multiline(geom);
when 'ST_Point' then
return geoc_bd09towgs84_point(geom);
when 'ST_MultiPoint' then
return geoc_bd09towgs84_multipoint(geom);
when 'ST_Polygon' then
return geoc_bd09towgs84_polygon(geom);
when 'ST_MultiPolygon' then
return geoc_bd09towgs84_multipolygon(geom);
ELSE
RETURN null;
END CASE;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09towgs84_line"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
p_p geometry;
p_t geometry;
z_t geometry;
i int;
BEGIN
i:=1;
while i <= st_npoints(geom) LOOP
p_p := st_pointn(geom,i);
p_t := geoc_bd09towgs84_point(p_p);
geom:=st_setpoint(geom,i-1,p_t);
i:=i+1;
end LOOP;
return geom;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09towgs84_multiline"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_bd09towgs84_line(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
CREATE OR REPLACE FUNCTION "public"."geoc_bd09towgs84_multipoint"("geom" "public"."geometry")
RETURNS "public"."geometry" AS $BODY$
DECLARE
i geometry;
transform_i geometry;
multiArr geometry[];
BEGIN
multiArr:='{}'::geometry[];
for i in EXECUTE $Q$ select (st_dump($1)).geom $Q$ using geom LOOP
transform_i :=geoc_bd09towgs84_point(i);
multiArr := array_append(multiArr, transform_i);
end LOOP;
return st_multi(ST_Union(multiArr));
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
查询经纬度属于哪个区域
SELECT "字段名" FROM "表名" WHERE ST_Contains( geom ,st_geometryfromtext('POINT(120.1 30.1)',4326) )='t'
查询在指定区域的所有数据(表中包含经纬度)
SELECT *
FROM 表名
where
ST_Contains((SELECT geom FROM province WHERE province = '内蒙古自治区'), st_geometryfromtext('POINT('|| longitude ||' '|| latitude ||')',4326))='t'
postGIS相关函数
1. OGC标准函数
管理函数:
添加几何字段 AddGeometryColumn(, , , , , )
删除几何字段 DropGeometryColumn(, , )
检查数据库几何字段并在geometry_columns中归档 Probe_Geometry_Columns()
给几何对象设置空间参考(在通过一个范围做空间查询时常用) ST_SetSRID(geometry, integer)
几何对象关系函数:
获取两个几何对象间的距离 ST_Distance(geometry, geometry)
如果两个几何对象间距离在给定值范围内,则返回TRUE ST_DWithin(geometry, geometry, float)
判断两个几何对象是否相等
(比如LINESTRING(0 0, 2 2)和LINESTRING(0 0, 1 1, 2 2)是相同的几何对象) ST_Equals(geometry, geometry)
判断两个几何对象是否分离 ST_Disjoint(geometry, geometry)
判断两个几何对象是否相交 ST_Intersects(geometry, geometry)
判断两个几何对象的边缘是否接触 ST_Touches(geometry, geometry)
判断两个几何对象是否互相穿过 ST_Crosses(geometry, geometry)
判断A是否被B包含 ST_Within(geometry A, geometry B)
判断两个几何对象是否是重叠 ST_Overlaps(geometry, geometry)
判断A是否包含B ST_Contains(geometry A, geometry B)
判断A是否覆盖 B ST_Covers(geometry A, geometry B)
判断A是否被B所覆盖 ST_CoveredBy(geometry A, geometry B)
通过DE-9IM 矩阵判断两个几何对象的关系是否成立 ST_Relate(geometry, geometry, intersectionPatternMatrix)
获得两个几何对象的关系(DE-9IM矩阵) ST_Relate(geometry, geometry)
几何对象处理函数:
获取几何对象的中心 ST_Centroid(geometry)
面积量测 ST_Area(geometry)
长度量测 ST_Length(geometry)
返回曲面上的一个点 ST_PointOnSurface(geometry)
获取边界 ST_Boundary(geometry)
获取缓冲后的几何对象 ST_Buffer(geometry, double, [integer])
获取多几何对象的外接对象 ST_ConvexHull(geometry)
获取两个几何对象相交的部分 ST_Intersection(geometry, geometry)
将经度小于0的值加360使所有经度值在0-360间 ST_Shift_Longitude(geometry)
获取两个几何对象不相交的部分(A、B可互换) ST_SymDifference(geometry A, geometry B)
从A去除和B相交的部分后返回 ST_Difference(geometry A, geometry B)
返回两个几何对象的合并结果 ST_Union(geometry, geometry)
返回一系列几何对象的合并结果 ST_Union(geometry set)
用较少的内存和较长的时间完成合并操作,结果和ST_Union相同 ST_MemUnion(geometry set)
几何对象存取函数:
获取几何对象的WKT描述 ST_AsText(geometry)
获取几何对象的WKB描述 ST_AsBinary(geometry)
获取几何对象的空间参考ID ST_SRID(geometry)
获取几何对象的维数 ST_Dimension(geometry)
获取几何对象的边界范围 ST_Envelope(geometry)
判断几何对象是否为空 ST_IsEmpty(geometry)
判断几何对象是否不包含特殊点(比如自相交) ST_IsSimple(geometry)
判断几何对象是否闭合 ST_IsClosed(geometry)
判断曲线是否闭合并且不包含特殊点 ST_IsRing(geometry)
获取多几何对象中的对象个数 ST_NumGeometries(geometry)
获取多几何对象中第N个对象 ST_GeometryN(geometry,int)
获取几何对象中的点个数 ST_NumPoints(geometry)
获取几何对象的第N个点 ST_PointN(geometry,integer)
获取多边形的外边缘 ST_ExteriorRing(geometry)
获取多边形内边界个数 ST_NumInteriorRings(geometry)
同上 ST_NumInteriorRing(geometry)
获取多边形的第N个内边界 ST_InteriorRingN(geometry,integer)
获取线的终点 ST_EndPoint(geometry)
获取线的起始点 ST_StartPoint(geometry)
获取几何对象的类型 GeometryType(geometry)
类似上,但是不检查M值,即POINTM对象会被判断为point ST_GeometryType(geometry)
获取点的X坐标 ST_X(geometry)
获取点的Y坐标 ST_Y(geometry)
获取点的Z坐标 ST_Z(geometry)
获取点的M值 ST_M(geometry)
几何对象构造函数:
参考语义: Text:WKT WKB:WKB Geom:Geometry M:Multi Bd:BuildArea Coll:Collection ST_GeomFromText(text,[])
ST_PointFromText(text,[])
ST_LineFromText(text,[])
ST_LinestringFromText(text,[])
ST_PolyFromText(text,[])
ST_PolygonFromText(text,[])
ST_MPointFromText(text,[])
ST_MLineFromText(text,[])
ST_MPolyFromText(text,[])
ST_GeomCollFromText(text,[])
ST_GeomFromWKB(bytea,[])
ST_GeometryFromWKB(bytea,[])
ST_PointFromWKB(bytea,[])
ST_LineFromWKB(bytea,[])
ST_LinestringFromWKB(bytea,[])
ST_PolyFromWKB(bytea,[])
ST_PolygonFromWKB(bytea,[])
ST_MPointFromWKB(bytea,[])
ST_MLineFromWKB(bytea,[])
ST_MPolyFromWKB(bytea,[])
ST_GeomCollFromWKB(bytea,[])
ST_BdPolyFromText(text WKT, integer SRID)
ST_BdMPolyFromText(text WKT, integer SRID)
-
PostGIS扩展函数
管理函数:
删除一个空间表(包括geometry_columns中的记录) DropGeometryTable([], ) 更新空间表的空间参考 UpdateGeometrySRID([], , , ) 更新空间表的统计信息 update_geometry_stats([, ])
参考语义: Geos:GEOS库 Jts:JTS库 Proj:PROJ4库 postgis_version()
postgis_lib_version()
postgis_lib_build_date()
postgis_script_build_date()
postgis_scripts_installed()
postgis_scripts_released()
postgis_geos_version()
postgis_jts_version()
postgis_proj_version()
postgis_uses_stats()
postgis_full_version()
几何操作符:
A范围=B范围 A = B
A范围覆盖B范围或A范围在B范围左侧 A &<> B
A范围在B范围左侧 A <<>> B
A范围覆盖B范围或A范围在B范围下方 A &<| B A范围覆盖B范围或A范围在B范围上方 A |&> B
A范围在B范围下方 A <<| B A范围在B范围上方 A |>> B
A=B A ~= B
A范围被B范围包含 A @ B
A范围包含B范围 A ~ B
A范围覆盖B范围 A && B
几何量测函数:
量测面积 ST_Area(geometry)
根据经纬度点计算在地球曲面上的距离,单位米,地球半径取值6370986米 ST_distance_sphere(point, point)
类似上,使用指定的地球椭球参数 ST_distance_spheroid(point, point, spheroid)
量测2D对象长度 ST_length2d(geometry)
量测3D对象长度 ST_length3d(geometry)
根据经纬度对象计算在地球曲面上的长度 ST_length_spheroid(geometry,spheroid)
ST_length3d_spheroid(geometry,spheroid)
量测两个对象间距离 ST_distance(geometry, geometry)
量测两条线之间的最大距离 ST_max_distance(linestring,linestring)
量测2D对象的周长 ST_perimeter(geometry)
ST_perimeter2d(geometry)
量测3D对象的周长 ST_perimeter3d(geometry)
量测两点构成的方位角,单位弧度 ST_azimuth(geometry, geometry)
几何对象输出:
参考语义: NDR:Little Endian XDR:big-endian HEXEWKB:Canonical SVG:SVG 格式 GML:GML 格式 KML:KML 格式 GeoJson:GeoJson 格式
ST_AsBinary(geometry,{'NDR'|'XDR'})
ST_AsEWKT(geometry)
ST_AsEWKB(geometry, {'NDR'|'XDR'})
ST_AsHEXEWKB(geometry, {'NDR'|'XDR'})
ST_AsSVG(geometry, [rel], [precision])
ST_AsGML([version], geometry, [precision])
ST_AsKML([version], geometry, [precision])
ST_AsGeoJson([version], geometry, [precision], [options])
几何对象创建:
参考语义: Dump:转储 ST_GeomFromEWKT(text)
ST_GeomFromEWKB(bytea)
ST_MakePoint(, , [], [])
ST_MakePointM(, , )
ST_MakeBox2D(, )
ST_MakeBox3D(, )
ST_MakeLine(geometry set)
ST_MakeLine(geometry, geometry)
ST_LineFromMultiPoint(multipoint)
ST_MakePolygon(linestring, [linestring[]])
ST_BuildArea(geometry)
ST_Polygonize(geometry set)
ST_Collect(geometry set)
ST_Collect(geometry, geometry)
ST_Dump(geometry)
ST_DumpRings(geometry)
几何对象编辑:
给几何对象添加一个边界,会使查询速度加快 ST_AddBBOX(geometry)
删除几何对象的边界 ST_DropBBOX(geometry)
添加、删除、设置点 ST_AddPoint(linestring, point, [])
ST_RemovePoint(linestring, offset)
ST_SetPoint(linestring, N, point)
几何对象类型转换 ST_Force_collection(geometry)
ST_Force_2d(geometry)
ST_Force_3dz(geometry), ST_Force_3d(geometry),
ST_Force_3dm(geometry)
ST_Force_4d(geometry)
ST_Multi(geometry)
将几何对象转化到指定空间参考 ST_Transform(geometry,integer)
对3D几何对象作仿射变化 ST_Affine(geometry, float8, float8, float8, float8, float8, float8, float8, float8, float8, float8, float8, float8)
对2D几何对象作仿射变化 ST_Affine(geometry, float8, float8, float8, float8, float8, float8)
对几何对象作偏移 ST_Translate(geometry, float8, float8, float8)
对几何对象作缩放 ST_Scale(geometry, float8, float8, float8)
对3D几何对象作旋转 ST_RotateZ(geometry, float8)
ST_RotateX(geometry, float8)
ST_RotateY(geometry, float8)
对2D对象作偏移和缩放 ST_TransScale(geometry, float8, float8, float8, float8)
反转 ST_Reverse(geometry)
转化到右手定则 ST_ForceRHR(geometry)
参考IsSimple函数
使用Douglas-Peuker算法 ST_Simplify(geometry, tolerance)
ST_SimplifyPreserveTopology(geometry, tolerance)
讲几何对象顶点捕捉到网格 ST_SnapToGrid(geometry, originX, originY, sizeX, sizeY)
ST_SnapToGrid(geometry, sizeX, sizeY), ST_SnapToGrid(geometry, size)
第二个参数为点,指定原点坐标 ST_SnapToGrid(geometry, geometry, sizeX, sizeY, sizeZ, sizeM)
分段 ST_Segmentize(geometry, maxlength)
合并为线 ST_LineMerge(geometry)
线性参考:
根据location(0-1)获得该位置的点 ST_line_interpolate_point(linestring, location)
获取一段线 ST_line_substring(linestring, start, end)
根据点获取location(0-1) ST_line_locate_point(LineString, Point)
根据量测值获得几何对象 ST_locate_along_measure(geometry, float8)
根据量测值区间获得几何对象集合 ST_locate_between_measures(geometry, float8, float8)
杂项功能函数:
几何对象的摘要 ST_Summary(geometry)
几何对象的边界 ST_box2d(geometry)
ST_box3d(geometry)
多个几何对象的边界 ST_extent(geometry set)
0=2d, 1=3dm, 2=3dz, 3=4d ST_zmflag(geometry)
是否包含Bounding Box ST_HasBBOX(geometry)
几何对象的维数:2、3、4 ST_ndims(geometry)
子对象的个数 ST_nrings(geometry)
ST_npoints(geometry)
对象是否验证成功 ST_isvalid(geometry)
扩大几何对象 ST_expand(geometry, float)
计算一个空间表的边界范围 ST_estimated_extent([schema], table, geocolumn)
获得空间参考 ST_find_srid(, , )
几何对象使用的内存大小,单位byte ST_mem_size(geometry)
点是否在圆上 ST_point_inside_circle(,,,)
获取边界的X、Y、Z ST_XMin(box3d)
ST_YMin(box3d)
ST_ZMin(box3d)
ST_XMax(box3d)
ST_YMax(box3d)
ST_ZMax(box3d)
构造一个几何对象的数组 ST_Accum(geometry set)
长事务支持:
启用/关闭长事务支持,重复调用无副作用 EnableLongTransactions()
DisableLongTransactions()
检查对行的update和delete操作是否已授权 CheckAuth([],, )
锁定行 LockRow([],, , , [])
解锁行 UnlockRows()
在当前事务中添加授权ID AddAuth()
其它还有SQL-MM和ArcSDE样式的函数支持,可以参考http://postgis.refractions.net/documentation/manual-1.3/ch06.html#id2750611,这里就不详细列了。