[GRASS-SVN] r38162 - in grass-addons/vector: . v.in.postgis

svn_grass at osgeo.org svn_grass at osgeo.org
Thu Jul 2 11:01:36 EDT 2009


Author: mathieug
Date: 2009-07-02 11:01:35 -0400 (Thu, 02 Jul 2009)
New Revision: 38162

Added:
   grass-addons/vector/v.in.postgis/
   grass-addons/vector/v.in.postgis/v.in.postgis.sqlquery
   grass-addons/vector/v.in.postgis/v.in.postgis.sqlquery.html
   grass-addons/vector/v.in.postgis/v_in_postgis.py
   grass-addons/vector/v.in.postgis/v_in_postgis_tests.py
Log:
python implementation + unit test module completed + renamed module

Added: grass-addons/vector/v.in.postgis/v.in.postgis.sqlquery
===================================================================
--- grass-addons/vector/v.in.postgis/v.in.postgis.sqlquery	                        (rev 0)
+++ grass-addons/vector/v.in.postgis/v.in.postgis.sqlquery	2009-07-02 15:01:35 UTC (rev 38162)
@@ -0,0 +1,380 @@
+#!/bin/sh
+#
+############################################################################
+#
+# MODULE:       v.in.postgis.sqlquery
+# AUTHOR(S):	Mathieu Grelier, 2007 (greliermathieu at gmail.com)
+# PURPOSE:		postgis data manipulation in grass from arbitrary sql queries
+# COPYRIGHT:	(C) 2007 Mathieu Grelier
+#
+#		This program is free software under the GNU General Public
+#		License (>=v2). Read the file COPYING that comes with GRASS
+#		for details.
+#
+#############################################################################
+
+
+#%Module
+#%  description: Create a grass layer from any sql query in postgis 
+#%  keywords: postgis, grass layer, sql 
+#%End
+#%option
+#% key: sqlquery
+#% type: string
+#% description: Any sql query returning a recordset with geometry for each row 
+#% required : yes
+#%end
+#%option
+#% key: geometryfield
+#% type: string
+#% answer: the_geom
+#% description: Name of the source geometry field. Usually defaults to the_geom but needed if a geometry function was used (for example, centroid), or if the table has many geometry columns.
+#% required : yes
+#%end
+#%option
+#% key: output
+#% type: string
+#% answer: postgis_sqlquery
+#% description: Name of the geographic postgis table where to place the query results. Will be the name of the imported grass layer. If -d flag is set, this table is deleted and replaced by a dbf attribute table. Use a different name than the original. Do not use capital letters
+#% required : no
+#%end
+#%flag
+#% key: d
+#% description: import result in grass dbf format (no new table in postgis). If not set, the grass layer will be directly connected to the postgis new table
+#%end
+#%flag
+#% key: z
+#% description: use -z for v.in.ogr (create 3D output).
+#%end
+#%flag
+#% key: r
+#% description: use -o for v.in.ogr (override dataset projection)
+#%end
+#%flag
+#% key: g
+#% description: add a gist index to the imported table in postgis (useless with the d flag)
+#%end
+
+if  [ -z "$GISBASE" ] ; then
+    echo "You must be in GRASS GIS to run this program."
+ 	exit 1
+fi   
+
+if [ "$1" != "@ARGS_PARSED@" ] ; then
+    exec g.parser "$0" "$@"
+fi
+
+## Config : you may need to fix these values
+#####################################
+#uncomment one of the home dir line depending on your system
+#linux
+homedir="$HOME"
+#windows (fix this path as it depends on the user login)
+#homedir="C:\Documents and Settings\your.login"
+
+#fix this path
+if [ -z "$LOGDIR" ] ; then
+	LOGDIR="$HOME"
+fi
+
+#default for grass6
+grassloginfile="$homedir"/.grasslogin6
+
+## GRASS team recommandations
+#####################################
+
+PROG=`basename $0`
+
+# check if we have awk
+if [ ! -x "`which awk`" ] ; then
+    echo "$PROG: awk required, please install awk or gawk first"
+    exit 1
+fi
+
+# setting environment, so that awk works properly in all languages
+unset LC_ALL
+LC_NUMERIC=C
+export LC_NUMERIC
+
+## exit procedures
+#####################################
+
+scriptend()
+{   
+	\rm -f "$TMPFILE1"
+	\rm -f "$TMPFILE2"
+}
+
+userbreakprocedure()
+{
+    echo "User break!"
+	scriptend
+}
+# shell check for user break (signal list: trap -l)
+trap "userbreakprocedure" 2 3 6 9 15 19
+
+#callable only after data has been imported
+scripterror()
+{
+	echo "script end cleanup:" >> "$LOGFILE" 2>&1	
+	echo "try to remove temp postgis table" >> "$LOGFILE" 2>&1
+	echo "DROP TABLE "$GIS_OPT_OUTPUT"" | db.execute >> "$TMPFILE2" 2>&1
+	echo "try to remove temp grass layer" >> "$LOGFILE" 2>&1
+	g.remove vect=tmpoutput >> "$TMPFILE2" 2>&1	
+	echo "execution failed" >> "$LOGFILE"
+	echo "script end cleanup:" >> "$LOGFILE" 2>&1
+	scriptend
+	exit 1
+}
+
+scriptsuccess()
+{
+	echo "execution ok" >> "$LOGFILE"	
+	echo "script end cleanup:" >> "$LOGFILE" 2>&1	
+	scriptend
+	exit 0
+}
+
+## necessary checks
+#####################################
+
+#this file will collect info from stdout and stderr (v.in.ogr for example outputs on stderr).
+LOGFILE="$LOGDIR/v.in.postgis.sqlquery.log"
+
+TMPFILE1="`g.tempfile pid=$$`"
+TMPFILE2="`g.tempfile pid=$$`"
+if [ $? -ne 0 ] || [ -z "$TMPFILE1" ] || [ -z "$TMPFILE2" ]; then
+	echo "ERROR: unable to create temporary files" 1>&2
+fi
+
+echo "v.in.postgis.sqlquery:" >> "$LOGFILE"
+echo "$GIS_OPT_SQLQUERY" >> "$LOGFILE"
+
+echo "check if .grasslogin file is found:" >> "$LOGFILE"
+if [ ! -r "$grassloginfile" ] ;then
+	echo "ERROR: .grasslogin file was not found. Use db.login before using this script or modify the config section in the script." 1>&2
+	scriptend
+	exit 1
+fi
+
+echo "check if grass layer already exists:" >> "$LOGFILE"
+eval `g.findfile element=vector file="$GIS_OPT_OUTPUT"`	
+if [ "$file" ] ; then
+	if [ -z "$GRASS_OVERWRITE" ] || [ "$GRASS_OVERWRITE" -eq 0 ]; then
+		echo "ERROR: vector map '$GIS_OPT_OUTPUT' already exists in mapset search path. Use the --o flag to overwrite or remove it before." 1>&2
+		scriptend
+		exit 1
+	else
+		echo "WARNING: vector map '$GIS_OPT_OUTPUT' will be overwritten." >> "$LOGFILE" 2>&1
+		#we must use g.remove to implement overwrite as it is not a valid option of v.in.ogr for now
+		g.remove vect="$GIS_OPT_OUTPUT" >> "$LOGFILE" 2>&1
+	fi
+fi
+
+#previous script execution may have not removed temporary elements
+echo "script start cleanup:" >> "$LOGFILE" 2>&1
+#test if a TEMPGEOTABLENAME table already exists. If yes, was it created by this script ? If yes, delete it.
+echo "SELECT CAST(tablename AS text) FROM pg_tables WHERE schemaname='public'" | db.select -c > "$TMPFILE1"
+if grep -q -x "$GIS_OPT_OUTPUT" "$TMPFILE1" ; then 
+	comment=$(echo "SELECT obj_description((SELECT c.oid FROM pg_catalog.pg_class c WHERE c.relname='"$GIS_OPT_OUTPUT"'), 'pg_class') AS comment" | db.select -c)
+	if [ "$comment" = "created_with_v.in.postgis.sqlquery" ]; then
+		echo "DROP TABLE "$GIS_OPT_OUTPUT"" | db.execute >> "$TMPFILE2" 2>&1
+	else
+		echo "ERROR: a table with the name "$GIS_OPT_OUTPUT" already exists and was not created by this script." 1>&2
+		scriptend
+		exit 1
+	fi
+fi
+
+## import
+######################################
+#must be done before call.
+#db.login ...
+#db.connect ...
+
+#grass doesn't support importing postgis views
+#So we use a create table as statement to import a kind of view with v.in.ogr
+echo "try to import data:" >> "$LOGFILE" 2>&1
+echo "CREATE TABLE "$GIS_OPT_OUTPUT" AS ""$GIS_OPT_SQLQUERY" | db.execute >> "$LOGFILE" 2>&1
+if [ $? -ne 0 ] ; then
+	echo "ERROR: an error occurred during sql import. Check your connection to the database and your sql query." 1>&2
+	scriptend
+	exit 1
+fi
+#we use also postgres comments as a specific mark for these tables. When we delete this table in the cleanup procedure using the layer name, we will check for this mark to ensure another table is not deleted, if the given layer name correspond to an existing table in the database. 
+echo "COMMENT ON TABLE "$GIS_OPT_OUTPUT" IS 'created_with_v.in.postgis.sqlquery'" | db.execute >> "$LOGFILE" 2>&1
+if [ $? -ne 0 ] ; then
+	echo "ERROR: an error occurred during commenting the table." 1>&2
+	scripterror
+fi
+
+#if -d flag wasn't not selected, can't import if query result already have a cat column
+#todo : add cat_ column in this case, as v.in.ogr with dbf driver do 
+if [ "$GIS_FLAG_D" -eq 0 ] ; then
+	tmp_pkey_name="tmp_pkey"_"$GIS_OPT_OUTPUT"
+	#with the pg driver (not the dbf one), v.in.ogr need a 'cat' column for index creation 
+	echo "ALTER TABLE "$GIS_OPT_OUTPUT" ADD COLUMN cat serial NOT NULL" | db.execute >> "$LOGFILE" 2>&1
+	if [ $? -ne 0 ] ; then
+		echo "WARNING: unable to add a 'cat' column. A column named 'CAT' or 'cat' may be present in your input data. This column is reserved for Grass to store categories."  1>&2
+	fi
+	echo "ALTER TABLE "$GIS_OPT_OUTPUT" ADD CONSTRAINT "$tmp_pkey_name" PRIMARY KEY (cat)" | db.execute >> "$LOGFILE" 2>&1
+	if [ $? -ne 0 ] ; then
+		echo "ERROR: unable to add temporary primary key" 1>&2
+		scripterror
+	fi
+fi
+
+#we need to use the postgis AddGeometryColumn function so that v.in.ogr will work. 
+echo "retrieving geometry info:" >> "$LOGFILE"
+#first, which table?
+geometry_column="$GIS_OPT_GEOMETRYFIELD"
+#if there is more than one geometry type in the query result table, we use the generic GEOMETRY type
+echo "SELECT DISTINCT GeometryType("$geometry_column") FROM "$GIS_OPT_OUTPUT"" | db.select -c > "$TMPFILE1"
+nb=$(cat "$TMPFILE1" | wc -l)
+if [ "$nb" -eq 1 ] ; then
+	type=$(awk '{print $1}' "$TMPFILE1")
+	echo "type=$type" >> "$LOGFILE" 2>&1
+else
+	type="GEOMETRY"
+fi
+#same thing with number of dimensions. If the query is syntactically correct but returns no geometry, this step will cause an error.
+echo "SELECT DISTINCT ndims("$geometry_column") FROM "$GIS_OPT_OUTPUT"" | db.select -c > "$TMPFILE1"
+nb=$(cat "$TMPFILE1" | wc -l)
+echo "number of dimensions=$nb" >> "$LOGFILE" 2>&1
+if [ "$nb" -eq 1 ] ; then
+	coord_dimension=$(awk '{print $1}' "$TMPFILE1")
+	echo "coord_dimension=$coord_dimension" >> "$LOGFILE" 2>&1
+else
+	echo "ERROR: the script was unable to retrieve a unique coordinates dimension for this query or no geometry is present. Check your sql query. " 1>&2
+	scripterror
+fi
+#srid
+echo "SELECT DISTINCT srid("$geometry_column") FROM "$GIS_OPT_OUTPUT"" | db.select -c > "$TMPFILE1"
+nb=$(cat "$TMPFILE1" | wc -l)
+if [ "$nb" -eq 1 ] ; then
+	srid=$(awk '{print $1}' "$TMPFILE1")
+	echo "srid=$srid" >> "$LOGFILE" 2>&1
+else
+	srid="-1"
+	echo "WARNING: the script was unable to retrieve a unique geometry srid for this query. Using undefined srid." 1>&2
+fi
+if [ $? -ne 0 ] ; then
+	echo "ERROR: the script was unable to retrieve geometry parameters" 1>&2
+	scripterror
+fi
+
+#we must remove other geometry columns than selected one that may be present in the query result, because v.in.ogr does not allow geometry columns selection
+#v.in.ogr take the first geometry column found in the table so if another geometry is present, as we use AddGeometryColumn fonction to copy selected geometry (see below), our geometry will appear after other geometries in the column list. In this case, v.in.ogr would not import the right geometry.
+echo "Checking for other geometries" >> "$LOGFILE"
+echo "SELECT column_name FROM(SELECT ordinal_position, column_name, udt_name FROM INFORMATION_SCHEMA.COLUMNS WHERE (TABLE_NAME='"$GIS_OPT_OUTPUT"') order by ordinal_position) as info WHERE udt_name='geometry' AND NOT column_name='"$geometry_column"'" | db.select -c > "$TMPFILE1" 2>> "$LOGFILE" 
+while read other_geo_column
+do
+if [ -n "$other_geo_column" ]; then 
+	echo "Found another geometry in the query result than selected one : ""$other_geo_column"" . Column will be dropped." >> "$LOGFILE"
+	echo "ALTER TABLE "$GIS_OPT_OUTPUT" DROP COLUMN "$other_geo_column"" | db.execute >> "$LOGFILE" 2>&1
+fi
+done < "$TMPFILE1"
+
+#we already inserted the geometry so we will recopy it in the newly created geometry column 
+echo "Create geometry column" >> "$LOGFILE"
+echo "ALTER TABLE "$GIS_OPT_OUTPUT" RENAME COLUMN "$geometry_column" TO the_geom_tmp" | db.execute >> "$LOGFILE" 2>&1
+echo "SELECT AddGeometryColumn('', '"$GIS_OPT_OUTPUT"','"$geometry_column"',"$srid",'"$type"',"$coord_dimension");" | db.select >> "$LOGFILE" 2>&1
+echo "UPDATE "$GIS_OPT_OUTPUT" SET "$geometry_column"=the_geom_tmp" | db.execute >> "$LOGFILE" 2>&1
+echo "ALTER TABLE "$GIS_OPT_OUTPUT" DROP COLUMN the_geom_tmp" | db.execute >> "$LOGFILE" 2>&1
+if [ "$GIS_FLAG_G" -eq 1 ] ; then
+	#we add a gist index
+	echo "CREATE INDEX "$GIS_OPT_OUTPUT"_index ON "$GIS_OPT_OUTPUT" USING GIST ("$geometry_column" GIST_GEOMETRY_OPS);" | db.execute >> 	"$LOGFILE" 2>&1
+fi
+if [ $? -ne 0 ] ; then
+	echo "ERROR: an error occured during geometry insertion." 1>&2
+	scripterror
+fi
+
+#now we are ready to achieve the dump with v.in.ogr
+#first, retrieve the connection parameters
+#sed -i option (original file replacement) is not implemented yet for msys (wingrass) so we use two files
+#host and db :
+db.connect -p > "$TMPFILE1"
+#keep only the database ligne
+sed '/^database/!d' "$TMPFILE1" > "$TMPFILE2"
+#retrieve host and db values for v.in.ogr dsn argument
+host=$(awk -F "," '{print $1}' "$TMPFILE2" | sed 's/database://')
+db=$(awk -F "," '{print $2}' "$TMPFILE2")
+
+#login and password
+#login file can contain many line so we must look for the one corresponding to the database we are connected to
+cat "$grassloginfile" > "$TMPFILE1"
+#space after "$db" is important is there are two lines in login file with similar db names
+sed -n "/pg "$host","$db" /p" "$TMPFILE1" > "$TMPFILE2"
+user=$(awk -F " " '{print $3}' "$TMPFILE2")
+password=$(awk -F " " '{print $4}' "$TMPFILE2")
+if [ $? -ne 0 ] ; then
+	echo "ERROR: sed was not able to retrieve your connection parameters from file." 1>&2
+	scripterror
+fi
+
+#uncomment to check parameters in logfile :
+#echo "connection parameters : " >> "$LOGFILE"
+#echo "$host" >> "$LOGFILE"
+#echo "$db" >> "$LOGFILE"
+#echo "user="$user"" >> "$LOGFILE"
+#echo "password="$password"" >> "$LOGFILE"
+
+#now prepare the options
+#-t option of v.in.ogr is dependant on -d flag : if the result table is keeped in postgresql, attributes don't have to be copied
+if [ "$GIS_FLAG_D" -eq 1 ] ; then
+	notable=""
+	outputname=tmpoutput
+	#we must shift to the dbf driver
+	eval `g.gisenv`
+	mkdir -p "$GISDBASE"/"$LOCATION_NAME"/"$MAPSET"/dbf/ >> "$LOGFILE" 2>&1
+	db.connect driver=dbf database='$GISDBASE/$LOCATION_NAME/$MAPSET/dbf/' >> "$LOGFILE" 2>&1
+else
+	notable="-t"
+	outputname="$GIS_OPT_OUTPUT"
+fi
+#-z option of v.in.ogr
+if [ "$GIS_FLAG_Z" -eq 1 ] ; then
+	output3D="-z"
+else
+	output3D=""
+fi
+#-o option of v.in.ogr ; flag -o doesn't seem to work
+if [ "$GIS_FLAG_R" -eq 1 ] ; then
+	overrideprojection="-o"
+else
+	overrideprojection=""
+fi
+
+#ready to call v.in.ogr now
+#Important : v.in.ogr outputs on stderr !
+#redirect stderr to file
+echo "call v.in.ogr" >> "$LOGFILE"
+dsn="PG:"$host" "$db" user="$user" password="$password""
+echo "dsn=$dsn" >> "$LOGFILE"
+echo "samere" >> "$LOGFILE"
+v.in.ogr $notable $output3D $overrideprojection dsn="$dsn" output="$outputname" layer="$GIS_OPT_OUTPUT" >> "$LOGFILE" 2>&1
+if [ $? -ne 0 ] ; then
+	echo "ERROR: an error occurred during v.in.ogr execution. Verify your connection parameters and ensure you used db.connect before launching this script. The -o flag may be necessary." 1>&2
+	#reconnect to pg to be able to remove the table
+	db.connect database=""$host","$db"" driver=pg
+	scripterror
+fi
+
+echo "post-import operations" >> "$LOGFILE"
+#if we import to grass dbf format, we must delete temporary postgresql table and rename the dbf layer to match the given output name
+if [ "$GIS_FLAG_D" -eq 1 ] ; then
+	g.rename vect=$outputname,$GIS_OPT_OUTPUT >> "$LOGFILE" 2>&1
+	db.connect database=""$host","$db"" driver=pg
+	echo "DROP TABLE "$GIS_OPT_OUTPUT"" | db.execute >> "$LOGFILE" 2>&1
+#else we work directly with postgis so the connection between imported grass layer and postgres attribute table must be explicit
+else
+	v.db.connect -o map="$GIS_OPT_OUTPUT" table="$GIS_OPT_OUTPUT" >> "$LOGFILE" 2>&1
+fi
+#delete temporary data in geometry_columns table
+echo "DELETE FROM geometry_columns WHERE f_table_name = '"$GIS_OPT_OUTPUT"'" | db.execute >> "$LOGFILE" 2>&1
+if [ $? -ne 0 ] ; then
+	echo "ERROR: error in post-import operation. Try to remove manually the postgis temp table (-d option) or set manually the connection between the layer and the table with v.db.connect." 1>&2
+fi
+
+scriptsuccess


Property changes on: grass-addons/vector/v.in.postgis/v.in.postgis.sqlquery
___________________________________________________________________
Added: svn:executable
   + *

Added: grass-addons/vector/v.in.postgis/v.in.postgis.sqlquery.html
===================================================================
--- grass-addons/vector/v.in.postgis/v.in.postgis.sqlquery.html	                        (rev 0)
+++ grass-addons/vector/v.in.postgis/v.in.postgis.sqlquery.html	2009-07-02 15:01:35 UTC (rev 38162)
@@ -0,0 +1,91 @@
+<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN">
+<html>
+<head>
+<title>v.in.postgis.sqlquery</title>
+<meta http-equiv="Content-Type" content="text/html; charset=iso-8859-1">
+<link rel="stylesheet" href="grassdocs.css" type="text/css">
+</head>
+<body bgcolor="white">
+
+<img src="grass.smlogo.gif" alt="GRASS logo"><hr align=center size=6 noshade>
+
+<h2>NAME</h2>
+<em><b>v.in.postgis.sqlquery</b></em>  - Create a grass layer from any sql query in postgis
+<h2>KEYWORDS</h2>
+postgis, grass layer, sql
+<h2>SYNOPSIS</h2>
+<b>v.in.postgis.sqlquery</b><br>
+<b>v.in.postgis.sqlquery help</b><br>
+<b>v.in.postgis.sqlquery</b> [-<b>dzrg</b>] <b>sqlquery</b>=<em>string</em> <b>geometryfield</b>=<em>string</em>   [<b>output</b>=<em>string</em>]
+
+<h3>Flags:</h3>
+<DL>
+<DT><b>-d</b></DT>
+<DD>import result in grass dbf format (no new table in postgis). If not set, the grass layer will be directly connected to the postgis new table</DD>
+
+<DT><b>-z</b></DT>
+<DD>use -z for v.in.ogr (create 3D output)</DD>
+
+<DT><b>-r</b></DT>
+<DD>use -o for v.in.ogr (override dataset projection)</DD>
+
+<DT><b>-g</b></DT>
+<DD>add a gist index to the imported table in postgis (useless with the d flag)</DD>
+
+
+
+<h3>Parameters:</h3>
+<DL>
+
+<DT><b>sqlquery</b>=<em>name</em></DT>
+<DD>Arbitrary sql query returning a recordset with geometry for each row </DD>
+
+<DT><b>geometryfield</b>=<em>name</em></DT>
+<DD>Name of the source geometry field. Usually defaults to the_geom but needed if a geometry function was used (for example, centroid), or if the table has many geometry columns</DD>
+
+<DT><b>output</b>=<em>name</em></DT>
+<DD>Name of the geographic postgis table where to place the query results. Will be the name of the imported grass layer. If -d flag is set, this table is deleted and replaced by a dbf attribute table. Use a different name than the original. Do not use capital letters </DD>
+
+
+</DL>
+<h2>DESCRIPTION</h2>
+
+<em>v.in.postgis.sqlquery</em> is a shell script to import as a grass layer the result of any sql query returning geometry. There are two main modes : i)grass native format import with attributes in a dbf file. No tables are added in PostGIS ; ii)Grass layer import with attributes directly connected to a temporary table in PostGIS containing the query results.
+Before using the script, db.connect (and eventually db.login) commands must have been called.
+The script has been tested with Linux and WinGrass. However, for winGrass, you should modify the home directory setting at the beginning of the script.
+Logfile is written in the directory specified by the LOGFILE environment variable (default : home directory).
+
+
+<h2>EXAMPLES</h2>
+
+<li><B>PostGIS sql query to grass map </B>(dbf attributes table, no new table in postgis)<BR>
+<div class="code"><pre>
+v.in.postgis.sqlquery -d sqlquery="SELECT * FROM zones, data WHERE zones.zone_id=data.zone_id AND value > 100" output=zones
+</pre></div>
+
+<li><B>work in Grass directly on a PostGIS table</B> (a new table is added in postgis, create a gist index)<BR>
+<div class="code"><pre>
+v.in.postgis.sqlquery -r -g sqlquery="SELECT value, centroid(geocolumn) AS locations FROM zones, data WHERE zones.zone_id=data.zone_id 
+GROUP BY name" geometryfield=locations output=locations
+</pre></div>
+
+<BR>
+
+<h2>SEE ALSO</h2>
+
+<em><a HREF="db.connect.html">db.connect</a></em>,
+<em><a HREF="db.login.html">db.login</a></em>,
+<em><a HREF="v.in.ogr">v.in.ogr</a></em>,
+
+
+<h2>AUTHOR</h2>
+
+Mathieu Grelier, greliermathieu at gmail.com
+<br>
+
+<p>
+<i>Last changed: $Date: 2007/10/10 12:10:14 $</i>
+<HR>
+<P><a href="index.html">Main index</a> - <a href="vector.html">vector index</a> - <a href="full_index.html">Full index</a></P>
+</body>
+</html>

Added: grass-addons/vector/v.in.postgis/v_in_postgis.py
===================================================================
--- grass-addons/vector/v.in.postgis/v_in_postgis.py	                        (rev 0)
+++ grass-addons/vector/v.in.postgis/v_in_postgis.py	2009-07-02 15:01:35 UTC (rev 38162)
@@ -0,0 +1,424 @@
+#!/usr/bin/python
+#-*- coding: utf-8 -*-
+#
+############################################################################
+#
+# MODULE:       v_in_postgis
+# AUTHOR(S):	Mathieu Grelier, 2009 (greliermathieu at gmail.com)
+# PURPOSE:		GRASS layer creation from arbitrary PostGIS sql queries
+# COPYRIGHT:	(C) 2009 Mathieu Grelier
+#
+#		This program is free software under the GNU General Public
+#		License (>=v2). Read the file COPYING that comes with GRASS
+#		for details.
+#
+#############################################################################
+
+#%Module
+#%  description: Create a grass layer from any sql query in postgis 
+#%  keywords: postgis, db, sql
+#%End
+#%option
+#% key: query
+#% type: string
+#% description: Any sql query returning a recordset with geometry for each row 
+#% required : yes
+#%end
+#%option
+#% key: geometryfield
+#% type: string
+#% answer: the_geom
+#% description: Name of the source geometry field (usually defaults to the_geom)
+#% required : yes
+#%end
+#%option
+#% key: output
+#% type: string
+#% answer: v_in_postgis
+#% description: name of the imported grass layer (do not use capital letters)
+#% required : no
+#%end
+#%flag
+#% key: d
+#% description: Import result in grass dbf format (no new table in postgis - if not set, new grass layer attributes will be connected to the result table)
+#%end
+#%flag
+#% key: o
+#% description: Use -o for v.in.ogr (override dataset projection)
+#%end
+#%flag
+#% key: g
+#% description: Add a gist index to the imported result table in postgis (useless with the d flag)
+#%end
+#%flag
+#% key: l
+#% description: Log process info to v_in_postgis.log
+#%end
+
+import sys
+import os
+import re
+from subprocess import Popen, PIPE
+import traceback
+
+##see http://initd.org/pub/software/psycopg/
+import psycopg2 as dbapi2
+##see http://trac.osgeo.org/grass/browser/grass/trunk/lib/python
+from grass import core as grass
+##only needed to use Komodo debugger with Komodo IDE. See http://aspn.activestate.com/ASPN/Downloads/Komodo/RemoteDebugging
+from dbgp.client import brk
+
+class GrassPostGisImporter():
+    
+    def __init__(self, options, flags):
+        ##options
+        self.query = options['query']
+        self.geometryfield = options['geometryfield'] if options['geometryfield'].strip() != '' else 'the_geom'
+        self.output = options['output'] if options['output'].strip() != '' else 'postgis_import'
+        ##flags
+        self.dbfFlag = True if flags['d'] is True else False
+        self.overrideprojFlag = True if flags['o'] is True else False
+        self.gistindexFlag = True if flags['g'] is True else False
+        self.logOutput = True if flags['l'] is True else False
+        ##others
+        logfilename = 'v_in_postgis.log'
+        self.logfile = os.path.join(os.getenv('LOGDIR'),logfilename) if os.getenv('LOGDIR') else logfilename
+        grass.try_remove(self.logfile)
+        ##default for grass6 ; you may need to fix this path
+        self.grassloginfile = os.path.join(os.getenv('HOME'),'.grasslogin6')
+        ##retrieve connection parameters
+        self.dbparams = self.__getDbInfos()
+        ##set db connection
+        self.db = dbapi2.connect(host=self.dbparams['host'], database=self.dbparams['db'], \
+user=self.dbparams['user'], password=self.dbparams['pwd'])
+        self.cursor = self.db.cursor()
+        ## uncomment if not default
+        #dbapi2.paramstyle = 'pyformat' 
+            
+    def __writeLog(self, log=''):
+        """Write the 'log' string to log file"""
+        if self.logfile is not None:
+            fileHandle = open(self.logfile, 'a')
+            log = log + '\n'
+            fileHandle.write(log)
+            fileHandle.close()
+            
+    def __getDbInfos(self):
+        """Create a dictionnary with all db params needed by v.in.ogr"""
+        try:
+            dbString = grass.parse_key_val(grass.read_command('db.connect', flags = 'p'), sep = ':')['database']
+            p = re.compile(',')
+            dbElems = p.split(dbString)
+            host = grass.parse_key_val(dbElems[0], sep = '=')['host']
+            db = grass.parse_key_val(dbElems[1], sep = '=')['dbname']
+            loginLine = self.executeCommand('sed -n "/pg ' + dbElems[0] + ','\
+                                                + dbElems[1] + ' /p" ' + self.grassloginfile, shell = True)
+            p = re.compile(' ')
+            loginElems = p.split(loginLine)
+            user = loginElems[-2].strip()
+            password = loginElems[-1].strip()
+            dbParamsDict = {'host':host, 'db':db, 'user':user, 'pwd':password}
+            return dbParamsDict
+        except:
+            raise GrassPostGisImporterError("Error while trying to retrieve database information.")
+    
+    def executeCommand(self, *args, **kwargs):
+        """Command execution method using Popen in two modes : shell mode or not"""
+        p = None
+        shell = True if 'shell' in kwargs and kwargs['shell'] is True else False
+        command = args[0]
+        if shell is True:
+            if self.logOutput is not False:
+                command = command + ' >> ' +  logFile
+            ##use redirection on stdout only
+            command = command + " 2>&1"
+            p = Popen(command, shell = shell, stdout = PIPE)
+        else:
+            kwargs['stdout'] = PIPE
+            kwargs['stderr'] = PIPE
+            p = grass.start_command(*args, **kwargs)
+        retcode = p.wait()
+        com = p.communicate()
+        message = ''
+        r = re.compile('\n')
+        for std in com:
+            if std is not None:
+                lines = r.split(std)
+                for elem in lines:
+                    message += str(elem).strip() + "\n"
+        if self.logOutput is not False and shell is False:
+            self.__writeLog(message)
+        if retcode == 0:
+            return message
+        else:
+            raise GrassPostGisImporterError(message)
+        
+    def printMessage(self, message, type = 'info'):
+        """Call grass message function corresponding to type"""
+        if type == 'error':
+            grass.error(message)
+        elif type == 'warning':
+            grass.warning(message)
+        elif type == 'info' and grass.gisenv()['GRASS_VERBOSE'] > 0:
+            grass.info(message)
+        if self.logOutput is True:
+            self.__writeLog(message)
+        
+    def checkLayers(self, output):
+        """
+        Test if the grass layer 'output' already exists.
+        
+        Note : for this to work with grass6.3, in find_file function from core.py,
+        command should be (n flag removed because 6.4 specific):
+        s = read_command("g.findfile", element = element, file = name, mapset = mapset)
+        """
+        self.printMessage("Check layers:")
+        ##Test if output vector map already exists.
+        testOutput = grass.find_file(output, element = 'vector')
+        if testOutput['fullname'] != '':
+            if not grass.overwrite() is True:
+                raise GrassPostGisImporterError("Vector map " + output + " already exists in mapset search path. \
+#Use the --o flag to overwrite.")
+            else:
+                self.printMessage("Vector map " + output + " will be overwritten.", type = 'warning')
+        return True
+        
+    def checkComment(self, output):
+        """Test if a table with the 'output' existing in PostGis have been created by the importer"""
+        testIfTableNameAlreadyExistsQuery = "SELECT CAST(tablename AS text) FROM pg_tables \
+                                            WHERE schemaname='public' \
+                                            AND CAST(tablename AS text)='" + output + "'"
+        self.cursor.execute(testIfTableNameAlreadyExistsQuery)
+        rows = self.cursor.fetchone()
+        if rows is not None and len(rows) > 0:
+            testCheckCommentQuery = "SELECT obj_description((SELECT c.oid FROM pg_catalog.pg_class c \
+                                    WHERE c.relname='" + output + "'), 'pg_class') AS comment"
+            self.cursor.execute(testCheckCommentQuery)
+            comment = self.cursor.fetchone()
+            if comment is not None and len(comment) == 1:
+                comment = comment[0]
+            if comment == "created_with_v_in_postgis.py":
+                self.cursor.execute("DROP TABLE " + output)
+            else:
+                raise GrassPostGisImporterError("ERROR: a table with the name " + output + " already exists \
+                                                and was not created by this script.")
+        return True
+    
+    def createPostgresTableFromQuery(self, output, query):
+        """
+        Create a table in postgresql populated with results from the query, and comment it so we
+        will later be able to figure out if this table was created by the importer (see checkLayers())
+        """
+        try:
+            createTableQuery = "CREATE TABLE " + str(output) + " AS " + str(query)
+            if self.logOutput is True:
+                self.__writeLog("Try to import data:")
+                self.__writeLog(createTableQuery)
+            self.cursor.execute(createTableQuery)
+            addCommentQuery = "COMMENT ON TABLE " + output + " IS 'created_with_v_in_postgis.py'"
+            self.cursor.execute(addCommentQuery)
+        except:
+            raise GrassPostGisImporterError("An error occurred during sql import. Check your connection \
+                                            to the database and your sql query.")
+    
+    def addCategory(self, output):
+        """
+        Add a category column in the result table
+        
+        With the pg driver (not the dbf one), v.in.ogr need a 'cat' column for index creation 
+        if -d flag wasn't not selected, can't import if query result already have a cat column
+        todo : add cat_ column in this case, as v.in.ogr with dbf driver do
+        """
+        try:
+            self.printMessage("Adding category column.")
+            s = "ALTER TABLE " + str(output) + " ADD COLUMN cat serial NOT NULL"
+            self.cursor.execute("ALTER TABLE " + str(output) + " ADD COLUMN cat serial NOT NULL")
+            tmp_pkey_name = "tmp_pkey_" + str(output)
+            self.cursor.execute("ALTER TABLE " + str(output) + " ADD CONSTRAINT " \
+            + tmp_pkey_name + " PRIMARY KEY (cat)")
+        except:
+            raise GrassPostGisImporterError("Unable to add a 'cat' column. A column named 'CAT' \
+                                            or 'cat' may be present in your input data. \
+                                            This column is reserved for Grass to store categories.")
+    
+    def getGeometryInfo(self, output, geometryfield):
+        """
+        Retrieve geometry parameters of the result.
+        
+        We need to use the postgis AddGeometryColumn function so that v.in.ogr will work.
+        This method aims to retrieve necessary info for AddGeometryColumn to work.
+        Returns a dict with
+        """
+        self.printMessage("Retrieving geometry info.")
+        ##if there is more than one geometry type in the query result table, we use the
+        ##generic GEOMETRY type
+        type="GEOMETRY"
+        self.cursor.execute("SELECT DISTINCT GeometryType(" + geometryfield + ") FROM " + output)
+        rows = self.cursor.fetchall()
+        if rows is not None and len(rows) == 1:
+            type = str(rows[0][0])
+        if rows is None or len(rows) == 0:
+            raise GrassPostGisImporterError("Unable to retrieve geometry type")
+        ##same thing with number of dimensions. If the query is syntactically correct but returns
+        ##no geometry, this step will cause an error.
+        ndims = 0
+        self.cursor.execute("SELECT DISTINCT ndims(" + geometryfield + ") FROM " + output)
+        rows = self.cursor.fetchall()
+        if rows is not None and len(rows) == 1:
+            ndims = str(rows[0][0])
+            if self.logOutput is True:
+                self.__writeLog("ndims=" + ndims)
+        else:
+            raise GrassPostGisImporterError("unable to retrieve a unique coordinates dimension for \
+                                            this query or no geometry is present. Check your sql query.")
+        ##srid
+        srid="-1"
+        self.cursor.execute("SELECT DISTINCT srid(" + geometryfield + ") FROM " + output)
+        rows = self.cursor.fetchall()
+        if rows is not None and len(rows[0]) == 1:
+            srid = str(rows[0][0])
+            if self.logOutput is True:
+                self.__writeLog("srid=" + srid)
+        elif rows is not None and len(rows[0]) > 1:
+            if self.logOutput is True:
+                self.__writeLog("Unable to retrieve a unique geometry srid for this query. \
+                             Using undefined srid.")
+        else:
+            raise GrassPostGisImporterError("Unable to retrieve geometry parameters.")
+        geoParamsDict = {'type':type, 'ndims':ndims, 'srid':srid}
+        return geoParamsDict
+        
+    def addGeometry(self, output, geometryField, geoParams, addGistIndex=False):
+        """Create geometry for result"""
+        try:
+            ##first we must remove other geometry columns than selected one that may be present in the query result,
+            ##because v.in.ogr does not allow geometry columns selection
+            ##v.in.ogr takes the first geometry column found in the table so if another geometry is present,
+            ##as we use AddGeometryColumn fonction to copy selected geometry (see below), our geometry will
+            ##appear after other geometries in the column list. In this case, v.in.ogr would not import the
+            ##right geometry.
+            self.printMessage("Checking for other geometries.")
+            self.cursor.execute("SELECT column_name FROM(SELECT ordinal_position, column_name, udt_name \
+                                FROM INFORMATION_SCHEMA.COLUMNS \
+                                WHERE (TABLE_NAME='" + output + "') ORDER BY ordinal_position) AS info \
+                                WHERE udt_name='geometry' AND NOT column_name='" + geometryField + "'")
+            rows = self.cursor.fetchall()
+            if rows is not None and len(rows) >= 1:
+                for otherGeoColumn in rows:
+                    if self.logOutput is True:
+                        self.__writeLog("Found another geometry in the query result than selected one: "\
+                                        + str(otherGeoColumn) + ". Column will be dropped.")
+                    self.cursor.execute("ALTER TABLE " + output + " DROP COLUMN " + otherGeoColumn)
+            ##we already inserted the geometry so we will recopy it in the newly created geometry column
+            if self.logOutput is True:
+                self.__writeLog("Create geometry column.")
+            self.cursor.execute("ALTER TABLE " + output + " RENAME COLUMN " + geometryField + " TO the_geom_tmp")
+            self.cursor.execute("SELECT AddGeometryColumn('', '" + output + "','" + geometryField + "',\
+                                "+ geoParams['srid'] + ",'" + geoParams['type'] + "'," + geoParams['ndims'] + ");")
+            self.cursor.execute("UPDATE " + output + " SET " + geometryField + " = the_geom_tmp")
+            self.cursor.execute("ALTER TABLE " + output + " DROP COLUMN  the_geom_tmp")
+            if addGistIndex is True:
+                self.cursor.execute("CREATE INDEX " + output + "_index ON " + output + " \
+                                    USING GIST (" + geometryField + " GIST_GEOMETRY_OPS);")
+        except:
+            raise GrassPostGisImporterError("An error occured during geometry insertion.")
+            
+    def importToGrass(self, output, geometryField, geoParams, toDbf = False, overrideProj = False):
+        """Wrapper for import and db connection of the result
+        
+        Note : for grass.gisenv() to work with grass6.3, in gisenv function from core.py,
+        command should be (n flag removed because 6.4 specific):
+        s = read_command("g.findfile", element = element, file = name, mapset = mapset)
+        """
+        ##dbf driver
+        flags = ''
+        outputname = output
+        if toDbf is True:
+            env = grass.gisenv()
+            dbfFolderPath = os.path.join(env['GISDBASE'].strip(";'"), env['LOCATION_NAME'].strip(";'"), \
+                                         env['MAPSET'].strip(";'"), 'dbf')
+            if not os.path.exists(dbfFolderPath):
+                os.mkdir(dbfFolderPath)
+            grass.run_command("db.connect", driver = 'dbf', database = dbfFolderPath) 
+        else:
+            flags += 't'
+        if overrideProj is True:
+            flags += 'o'
+
+        ##finally call v.in.ogr
+        self.printMessage("call v.in.ogr...")
+        dsn="PG:host=" + self.dbparams['host'] + " dbname=" + self.dbparams['db'] \
+        + " user=" + self.dbparams['user'] + " password=" + self.dbparams['pwd']
+        layername = output
+        cmd = self.executeCommand("v.in.ogr", dsn = dsn, output = outputname, layer = layername, \
+                          flags = flags, overwrite=True, quiet = False)
+        if toDbf is True:
+            grass.run_command("db.connect", driver = 'pg', database = 'host=' + self.dbparams['host'] + \
+                              ",dbname=" + self.dbparams['db'])
+            self.cursor.execute('DROP TABLE ' + output)
+        ##else we work directly with postgis so the connection between imported grass layer
+        ##and postgres attribute table must be explicit
+        else:
+            ##can cause segfaults if mapset name is too long:
+            cmd = self.executeCommand("v.db.connect", map = output, table = output, flags = 'o')
+        
+        ##delete temporary data in geometry_columns table
+        self.cursor.execute("DELETE FROM geometry_columns WHERE f_table_name = '" + output + "'")
+        pass
+            
+    def commitChanges(self):
+        """Commit current transaction"""
+        self.db.commit()
+    
+    def makeSqlImport(self):
+        """GrassPostGisImporter main sequence"""
+        ##1)check layers before starting
+        self.checkLayers(self.output)
+        ##2)query
+        self.createPostgresTableFromQuery(self.output, self.query)
+        ##3)cats
+        if self.dbfFlag is False:
+            self.addCategory(self.output)
+        ##4)geometry parameters
+        geoparams = self.getGeometryInfo(self.output, self.geometryfield)
+        ##5)new geometry
+        self.addGeometry(self.output, self.geometryfield, geoparams, self.gistindexFlag)
+        self.commitChanges()
+        ##6)v.in.ogr
+        self.importToGrass(self.output, self.geometryfield, geoparams, toDbf = self.dbfFlag, \
+                           overrideProj = self.overrideprojFlag)
+        ##7)post-import operations
+        self.commitChanges()
+                                                                                  
+class GrassPostGisImporterError(Exception):
+    """Errors specific to GrassPostGisImporter class"""
+    def __init__(self, message=''):
+        self.details = '\nDetails:\n'
+        exceptionType, exceptionValue, exceptionTraceback = sys.exc_info()
+        self.details += repr(traceback.format_exception(exceptionType, exceptionValue, exceptionTraceback))
+        self.message = message + "\n" + self.details
+
+def main():
+    exitStatus = 0
+    try:
+        postgisImporter = GrassPostGisImporter(options, flags)
+        postgisImporter.makeSqlImport()
+    except GrassPostGisImporterError, e1:
+        postgisImporter.printMessage(e1.message, type = 'error')
+        exitStatus = 1
+    except:
+        exceptionType, exceptionValue, exceptionTraceback = sys.exc_info()
+        errorMessage = "Unexpected error \n:" + \
+                       repr(traceback.format_exception(exceptionType, exceptionValue, exceptionTraceback))
+        postgisImporter.printMessage(errorMessage, type = 'error')
+        exitStatus = 1
+    else:
+        postgisImporter.printMessage("Done", type = 'info')
+    finally:
+        sys.exit(exitStatus)
+
+if __name__ == "__main__":
+    ### DEBUG : uncomment to start local debugging session
+    #brk(host="localhost", port=9000)
+    options, flags = grass.parser()
+    main()


Property changes on: grass-addons/vector/v.in.postgis/v_in_postgis.py
___________________________________________________________________
Added: svn:executable
   + *

Added: grass-addons/vector/v.in.postgis/v_in_postgis_tests.py
===================================================================
--- grass-addons/vector/v.in.postgis/v_in_postgis_tests.py	                        (rev 0)
+++ grass-addons/vector/v.in.postgis/v_in_postgis_tests.py	2009-07-02 15:01:35 UTC (rev 38162)
@@ -0,0 +1,310 @@
+#!/usr/bin/python
+#-*- coding: utf-8 -*-
+#
+############################################################################
+#
+# MODULE:       v_in_postgis_tests.py
+# AUTHOR(S):	Mathieu Grelier, 2009 (greliermathieu at gmail.com)
+# PURPOSE:		An attempt of a GRASS module unit test for v_in_postgis
+# COPYRIGHT:	(C) 2009 Mathieu Grelier
+#
+#		This program is free software under the GNU General Public
+#		License (>=v2). Read the file COPYING that comes with GRASS
+#		for details.
+#
+#############################################################################
+
+import sys
+import os
+import re
+
+##see http://trac.osgeo.org/grass/browser/grass/trunk/lib/python
+from grass import core as grass
+##only needed to use debugger with Komodo IDE. See http://aspn.activestate.com/ASPN/Downloads/Komodo/RemoteDebugging
+from dbgp.client import brk
+##see http://pyunit.sourceforge.net/
+import unittest
+##see http://initd.org/pub/software/psycopg/
+import psycopg2 as dbapi2
+
+importer = None
+db = None
+cursor = None
+host = None
+dbname = None
+user = None
+pwd = None
+query = None
+testTableName = None
+queryTableName = None
+geometryField = None
+geoparams = None
+
+class v_in_postgis_sqlquery_tests(unittest.TestCase):
+    
+    def setUp(self): 
+        grass.run_command("db.connect", driver = 'pg', database = 'host=' + host + ",dbname=" + dbname)
+    
+    def tearDown(self):
+        cleanUpQueryTable()
+    
+    def testGetDbInfos(self):
+        """Test if the importer is able to retrieve correctly the parameters dictionnary for current connection."""
+        self.assertEqual(importer.dbparams['host'],host)
+        self.assertEqual(importer.dbparams['db'],dbname)
+        self.assertEqual(importer.dbparams['user'],user)
+        self.assertEqual(importer.dbparams['pwd'],pwd)
+    
+    def testCheckLayers(self):
+        """Test if overwrite is working correctly"""
+        from v_in_postgis import GrassPostGisImporterError
+        os.environ['GRASS_OVERWRITE'] = '0'
+        createQueryTable()
+        importer.addGeometry(queryTableName, geometryField, geoparams, False)
+        importer.commitChanges()
+        importer.importToGrass(queryTableName, geometryField, geoparams, toDbf = False, overrideProj = True)
+        importer.commitChanges()
+        ##GRASS_OVERWRITE set to False, we can't import again the layer
+        self.assertRaises(GrassPostGisImporterError, importer.checkLayers, queryTableName)
+        cleanUpQueryTable()
+        ##now set to True, it should be possible
+        os.environ['GRASS_OVERWRITE'] = '1'
+        createQueryTable()
+        importer.addGeometry(queryTableName, geometryField, geoparams, False)
+        importer.commitChanges()
+        importer.importToGrass(queryTableName, geometryField, geoparams, toDbf = False, overrideProj = True)
+        importer.commitChanges()
+        try:
+            importer.checkLayers(queryTableName)
+        except Exception:
+            self.fail("CheckLayers was expected to be successful with --o flag.")
+        pass
+    
+    def testCheckComment(self):
+        """Test that we can't drop a table with the output name if it was not created by the importer."""
+        ##a table that was not tagged by the importer should not be overwritten
+        from v_in_postgis import GrassPostGisImporterError
+        os.environ['GRASS_OVERWRITE'] = '1'
+        self.assertRaises(GrassPostGisImporterError, importer.checkComment, testTableName)
+        pass
+    
+    def testImportGrassLayer(self):
+        """Test import sequence result in GRASS"""
+        ##preparation
+        importer.query = query
+        importer.output = queryTableName
+        importer.geometryfield = geometryField
+        importer.gistindexFlag = True
+        importer.overrideprojFlag = True
+        importer.dbfFlag = False
+        ##PostGIS import
+        importer.makeSqlImport()
+        testOutput = grass.find_file(queryTableName, element = 'vector')
+        self.assertTrue(testOutput['fullname'] != '')
+        pgdbconnectstring = "host=" + host + ",dbname=" + dbname
+        cmd = importer.executeCommand("v.db.connect", flags = 'g', map = queryTableName, driver = 'pg')
+        r = re.compile(' ')
+        dbinfos = r.split(cmd)
+        def trim(p): return str(p).strip()
+        dbinfos = map(trim, dbinfos)
+        self.assertEquals(dbinfos[0], '1')
+        self.assertEquals(dbinfos[1], queryTableName)
+        self.assertEquals(dbinfos[2], 'cat')
+        self.assertEquals(dbinfos[3], pgdbconnectstring)
+        self.assertEquals(dbinfos[4], 'pg')
+        ##cast is necessary
+        cmd = importer.executeCommand("echo 'SELECT CAST(COUNT (*) AS int) FROM " + queryTableName + "' | db.select -c", shell = True)
+        self.assertEquals(int(cmd[0]), 2)
+        cleanUpQueryTable()
+        #Dbf import
+        importer.dbfFlag = True
+        importer.makeSqlImport()
+        testOutput = grass.find_file(queryTableName, element = 'vector')
+        self.assertTrue(testOutput['fullname'] != '')
+        env = grass.gisenv()
+        dbfDbPath = os.path.join(env['GISDBASE'].strip(";'"), env['LOCATION_NAME'].strip(";'"), \
+                                         env['MAPSET'].strip(";'"), 'dbf')
+        cmd = importer.executeCommand("v.db.connect", flags = 'g', map = queryTableName, driver = 'dbf')
+        r = re.compile(' ')
+        dbinfos = r.split(cmd)
+        dbinfos = map(trim, dbinfos)
+        self.assertEquals(dbinfos[0], '1')
+        self.assertEquals(dbinfos[1], queryTableName)
+        self.assertEquals(dbinfos[2], 'cat')
+        self.assertEquals(dbinfos[3], dbfDbPath)
+        self.assertEquals(dbinfos[4], 'dbf')
+        cmd = importer.executeCommand("db.select", flags = 'c', table = queryTableName, \
+                                      database = dbfDbPath, driver = 'dbf')
+        r = re.compile('\n')
+        lines = r.split(cmd)
+        def validrecord(l): return len(str(l).strip()) > 0
+        result = filter(validrecord, lines)
+        self.assertEquals(len(result), 2)
+        
+    def testGetGeometryInfos(self):
+        """Test that we correctly retrieve geometry parameters from PostGis result table"""
+        createQueryTable()
+        params = importer.getGeometryInfo(queryTableName, geometryField)
+        self.assertEquals(params['type'], geoparams['type'])
+        self.assertEquals(params['ndims'], geoparams['ndims'])
+        self.assertEquals(params['srid'], geoparams['srid'])
+        ##needed
+        importer.commitChanges()
+    
+    def testAddingCategoryWithPgDriverIsNecessary(self):
+        """Test is the cat column addition is working and is still necessary with pg driver import
+        
+        cat column is necessary for GRASS to store categories.
+        For now, the pg driver for v.in.ogr doesn't doesn't add automatically this
+        cat column, whereas the dbf driver does. So the importer has a specific addCategory()
+        method, which necessity is tested here.
+        """
+        ##starting with postgis to dbf import : no need to use the addCategory() method is expected
+        from v_in_postgis import GrassPostGisImporterError
+        createQueryTable()
+        importer.addGeometry(queryTableName, geometryField, geoparams, False)
+        importer.commitChanges()
+        importer.importToGrass(queryTableName, geometryField, geoparams, toDbf = True, overrideProj = True)
+        importer.commitChanges()
+        try:
+            cmd = importer.executeCommand("v.univar", map = queryTableName, column = 'value')
+        except GrassPostGisImporterError:
+            self.fail("Categories should be retrieved with dbf driver.")
+        cleanUpQueryTable()
+        ##now same operations with pg driver : error is expected when GRASS use the cat column.
+        createQueryTable()
+        importer.addGeometry(queryTableName, geometryField, geoparams, False)
+        importer.commitChanges()
+        importer.importToGrass(queryTableName, geometryField, geoparams, False, True)
+        importer.commitChanges()
+        self.assertRaises(GrassPostGisImporterError, \
+                          importer.executeCommand, "v.univar", map = queryTableName, column = 'value')
+        cleanUpQueryTable()
+        ##now same operations with pg driver, after adding category column
+        ##with the importer : error should not occur.
+        createQueryTable()
+        importer.addGeometry(queryTableName, geometryField, geoparams, False)
+        importer.addCategory(queryTableName)
+        importer.commitChanges()
+        importer.importToGrass(queryTableName, geometryField, geoparams, False, True)
+        importer.commitChanges()
+        try:
+            cmd = importer.executeCommand("v.univar", map = queryTableName, column = 'value')
+        except GrassPostGisImporterError:
+            self.fail("Categories should be retrieved with pg driver when categories are added.")
+        
+    def testGeometryDuplicationIsNecessary(self):
+        """Test that we need to use the postGis' AddGeometryColumn function"""
+        createQueryTable()
+        importer.addCategory(queryTableName)
+        importer.commitChanges()
+        from v_in_postgis import GrassPostGisImporterError
+        self.assertRaises(GrassPostGisImporterError, importer.importToGrass, queryTableName, \
+                        geometryField, geoparams, False, True)
+        cleanUpQueryTable()
+        createQueryTable()
+        ##now addGeometry:
+        importer.addGeometry(queryTableName, geometryField, geoparams, False)
+        importer.addCategory(queryTableName)
+        importer.commitChanges()
+        try:
+            importer.importToGrass(queryTableName, geometryField, geoparams, False, True)
+        except Exception:
+            self.fail("Both operations are for now expected to be necessary.")
+        pass
+
+def createQueryTable():
+    importer.createPostgresTableFromQuery(queryTableName, query)
+    importer.commitChanges()
+    
+def cleanUpQueryTable():
+    db.rollback()
+    try:
+        importer.executeCommand("g.remove", vect = queryTableName, quiet = True)
+        cursor.execute('DROP TABLE ' + queryTableName)
+    except:
+        pass
+    try:
+        cursor.execute("DELETE FROM geometry_columns WHERE f_table_name = '" + queryTableName + "'")
+    except:
+        pass
+    db.commit()
+    
+def cleanUp():
+    db.rollback()
+    cleanUpQueryTable()
+    try:
+        importer.executeCommand("g.remove", vect = testTableName, quiet = True)
+        cursor.execute('DROP TABLE ' + testTableName)
+    except:
+        pass
+    try:
+        cursor.execute("DELETE FROM geometry_columns WHERE f_table_name = '" + testTableName + "'")
+    except:
+        pass
+    db.commit()
+    
+def suite():
+    alltests = unittest.TestSuite()
+    alltests.addTest(unittest.findTestCases(module))
+    return alltests
+
+if __name__ == '__main__':
+    ### DEBUG : uncomment to start local debugging session
+    #brk(host="localhost", port=9000)
+    currentDirectory = os.path.split(__file__)[0]
+    sys.path.append(currentDirectory)
+    from v_in_postgis import GrassPostGisImporter
+    ##test configuration
+    options = {'query':'', 'geometryfield':'', 'output':''}
+    flags = {'d':0, 'z':0, 'o':0, 'g':0, 'l':0}
+    importer = GrassPostGisImporter(options, flags)
+    module = __import__('v_in_postgis_tests')
+    host = 'localhost'
+    dbname = 'yourdb'
+    user = 'postgresuser'
+    pwd = 'yourpwd'
+    db = dbapi2.connect(host=host, database=dbname, user=user, password=pwd)
+    cursor = db.cursor()
+    testTableName = 'test_grass_import'
+    queryTableName = 'test_query'
+    geometryField = 'the_geom'
+    srid = '2154'
+    geoparams = {'type':'MULTIPOLYGON', 'ndims':'2', 'srid': srid}
+    query = 'select * from ' + testTableName + ' where id>1'
+    ##give access to test elements to module
+    module.importer = importer
+    module.db = db
+    module.cursor = cursor
+    module.host = host
+    module.dbname = dbname
+    module.user = user
+    module.pwd = pwd
+    module.testTableName = testTableName
+    module.queryTableName = queryTableName
+    module.geometryField = geometryField
+    module.geoparams = geoparams
+    module.query = query
+    ##test geo table
+    cursor.execute("CREATE TABLE " + testTableName + " ( id int4, label varchar(20), value real )")
+    cursor.execute("SELECT AddGeometryColumn('', '" + testTableName + "','" + geometryField + "'," + srid + ",'MULTIPOLYGON',2)")
+    cursor.execute("INSERT INTO " + testTableName + " (id, label, value, " + geometryField + ") VALUES (1, 'A Geometry', 10, \
+                        GeomFromText('MULTIPOLYGON(((771825.9029201793 6880170.713342139,771861.2893824165 \
+                        6880137.00894025,771853.633171779 6880129.128272728,771818.4675156211 \
+                        6880162.7242448665,771825.9029201793 6880170.713342139)))', " + srid + "))")
+    cursor.execute("INSERT INTO " + testTableName + " (id, label, value, " + geometryField + ") VALUES (2, 'Another Geometry', 20, \
+                        GeomFromText('MULTIPOLYGON(((771853.633171779 6880129.128272728,771842.2964842085 \
+                        6880117.197908178,771807.1308239839 6880150.79394592,771818.4675156211 \
+                        6880162.7242448665,771853.633171779 6880129.128272728)))', " + srid + "))")
+    cursor.execute("INSERT INTO " + testTableName + " (id, label, value, " + geometryField + ") VALUES (3, 'A last Geometry', 20, \
+                        GeomFromText('MULTIPOLYGON(((771807.1308239839 6880150.79394592,771842.2964842085 \
+                        6880117.197908178,771831.1791767566 6880105.270296125,771795.7209431691 \
+                        6880138.862761175,771807.1308239839 6880150.79394592)))', " + srid + "))")
+    cursor.execute("ALTER TABLE " + testTableName + " ADD CONSTRAINT test_pkey " + " PRIMARY KEY (id)")
+    db.commit()
+    os.environ['GRASS_VERBOSE'] = '0'
+    try:
+        unittest.main(defaultTest='suite')
+    finally:
+        module.cleanUp()
+        sys.exit(0)


Property changes on: grass-addons/vector/v.in.postgis/v_in_postgis_tests.py
___________________________________________________________________
Added: svn:executable
   + *



More information about the grass-commit mailing list