[Schmitzm-commits] r1696 - in trunk: schmitzm-core/src/main/java/de/schmitzm schmitzm-core/src/main/java/de/schmitzm/geotools/postgres schmitzm-core/src/main/java/de/schmitzm/postgres schmitzm-core/src/test/java/de/schmitzm schmitzm-gt/src/main/java/de/schmitzm/geotools/postgres

scm-commit@wald.intevation.org scm-commit at wald.intevation.org
Mon Aug 29 15:05:16 CEST 2011


Author: alfonx
Date: 2011-08-29 15:05:14 +0200 (Mon, 29 Aug 2011)
New Revision: 1696

Added:
   trunk/schmitzm-core/src/main/java/de/schmitzm/postgres/
   trunk/schmitzm-core/src/main/java/de/schmitzm/postgres/PGUtil.java
   trunk/schmitzm-core/src/test/java/de/schmitzm/postgres/
Removed:
   trunk/schmitzm-core/src/main/java/de/schmitzm/geotools/postgres/PGUtil.java
Modified:
   trunk/schmitzm-gt/src/main/java/de/schmitzm/geotools/postgres/PGUtilGT.java
Log:
PGUtil war in in einem falschen package ...geotools.... Daf?\195?\188r haben wir aber PGUtilGT

Deleted: trunk/schmitzm-core/src/main/java/de/schmitzm/geotools/postgres/PGUtil.java
===================================================================
--- trunk/schmitzm-core/src/main/java/de/schmitzm/geotools/postgres/PGUtil.java	2011-08-29 12:37:18 UTC (rev 1695)
+++ trunk/schmitzm-core/src/main/java/de/schmitzm/geotools/postgres/PGUtil.java	2011-08-29 13:05:14 UTC (rev 1696)
@@ -1,447 +0,0 @@
-package de.schmitzm.geotools.postgres;
-
-import java.sql.Connection;
-import java.sql.ResultSet;
-import java.sql.SQLException;
-import java.sql.Statement;
-import java.util.ArrayList;
-import java.util.List;
-
-import org.apache.log4j.Logger;
-
-import de.schmitzm.lang.LangUtil;
-
-/**
- * Hilfsmethoden für PostgreSQL. Die Dependency soll nur {@link Connection}
- * sein. In Hibernate kann über #doWork eine {@link Connection} erhalten werden.
- */
-public class PGUtil {
-	static final Logger log = Logger.getLogger(PGUtil.class);
-
-	/**
-	 * PostgreSQL Privilegien die per Grant einer Tabelle zugeordnet werden
-	 * können.<br/>
-	 * 
-	 * @see http://www.postgresql.org/docs/9.1/static/sql-grant.html
-	 */
-	public enum Privileges {
-		SELECT, INSERT, UPDATE, DELETE, REFERENCES, TEMPORARY, ALL_PRIVILEGES(
-				"ALL PRIVILEGES");
-
-		String sql;
-
-		Privileges() {
-			this.sql = super.toString();
-		}
-
-		Privileges(String sql) {
-			this.sql = sql;
-		}
-
-		@Override
-		public String toString() {
-			return this.sql;
-		}
-	}
-
-	/**
-	 * Fügt Privilegien für eine Rolle einer Tabelle hinzu.
-	 * 
-	 * @param tablename
-	 *            Tabellennamen, optional mit "schema.tablename"
-	 * @param targetRole
-	 *            Darf PUBLIC sein, oder Name einer ROLLE.
-	 * @param privileges
-	 *            List der zuzuordnenden Privilegien
-	 * @throws SQLException
-	 */
-	public static void grantPrivilegesOnTable(Connection c, String targetRole,
-			String tablename, Privileges... privileges) throws SQLException {
-		// GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
-		String sql = "GRANT "
-				+ LangUtil.stringConcatWithSep(",", (Object[]) privileges)
-				+ " ON " + tablename + " TO " + targetRole;
-		c.createStatement().executeUpdate(sql);
-	}
-
-	/**
-	 * Entfernt Privilegien für eine Rolle von einre Tabelle.
-	 * 
-	 * @param tablename
-	 *            Tabellennamen, optional mit "schema.tablename"
-	 * @param privileges
-	 *            List der zuzuordnenden Privilegien
-	 * @throws SQLException
-	 */
-	public static void revokePrivilegesOnTable(Connection c, String tablename,
-			String targetRole, Privileges... privileges) throws SQLException {
-		// GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
-		String sql = "REVOKE "
-				+ LangUtil.stringConcatWithSep(",", (Object[]) privileges)
-				+ " ON " + tablename + " FROM " + targetRole;
-		c.createStatement().executeUpdate(sql);
-	}
-
-	/**
-	 * Erstellt eine neue Rolle
-	 */
-	public static void createRole(Connection c, String rolename)
-			throws SQLException {
-		String sql = "CREATE ROLE " + rolename;
-		c.createStatement().executeUpdate(sql);
-	}
-
-	/**
-	 * Querys the <code>geometry_columns</code> table is part of every POSTGIS
-	 * installation and must/should describe the geometry columns and tables.
-	 */
-	static public String[] getColumnsDescribedInGeometryColumnsTable(Statement s) {
-		String[] columns = new String[0];
-		try {
-			ResultSet askGeoe = s
-					.executeQuery("SELECT f_table_name FROM geometry_columns;");
-			while (askGeoe.next()) {
-				columns = LangUtil.extendArray(columns, askGeoe.getString(1));
-			}
-		} catch (SQLException e) {
-			log.error(e, e);
-		}
-
-		return columns;
-
-	}
-
-	/**
-	 * Creates or Updates
-	 * 
-	 * @param tableName
-	 * @param geoColumnName
-	 * @param srid
-	 */
-	@Deprecated
-	// tut noch nicht
-	public static void createOrUpdateGeometrysColumnsEntry(String tableName,
-			String geoColumnName, int srid) {
-
-		String createGeometryEntrySQL = "INSERT INTO geometry_columns (f_table_catalog, f_table_schema, f_table_name, f_geometry_column, coord_dimension, srid, \"type\") VALUES ( '', 'public', '"
-				+ tableName
-				+ "', '"
-				+ geoColumnName
-				+ "', 2, "
-				+ srid
-				+ ",'MULTIPOLYGON' ) LIMIT 1;";
-	}
-
-	// TODO isGeoColumn();
-
-	/**
-	 * @param binding
-	 *            Eine "einfache" Javaklasse, die in PG abgebildet werden soll.
-	 * @return einen PG-spezifischen Datentypenamen für einen Javatyp zurück,
-	 *         z.b. "double precision" für <code>Double.class</code>
-	 */
-	public static String getColTypeName(Class<?> binding) {
-
-		if (binding.isAssignableFrom(Double.class)) {
-			return "double precision"; // eg 'number' at oracle
-		} else if (binding.isAssignableFrom(String.class)) {
-			return "text";
-		} else if (binding.isAssignableFrom(Integer.class)) {
-			return "integer";
-		} else if (binding.isAssignableFrom(Long.class)) {
-			return "bigint";
-		}
-
-		throw new RuntimeException("DB Type mapping for " + binding
-				+ " not yet implemented.");
-	}
-
-	/**
-	 * Legt ein Schema an, wenn es vorher nicht existierte.
-	 * 
-	 * @return <code>true</code> wenn das Schema neu angelegt wurde.
-	 */
-	public static boolean createSchemaIfNotExists(Connection c,
-			String schemaname) throws SQLException {
-		if (!existsSchema(c, schemaname)) {
-			c.createStatement().execute(
-					"create schema " + schemaname.toLowerCase());
-			return true;
-		}
-		return false;
-	}
-
-	/**
-	 * Liefert <code>true</code> wenn ein Schema mit dem Namen in der PG
-	 * Datenbank existiert.
-	 */
-	public static boolean existsSchema(Connection c, String schemaname)
-			throws SQLException {
-		ResultSet rs = c.createStatement().executeQuery(
-				"select 1 from pg_catalog.pg_namespace where nspname = '"
-						+ schemaname.toLowerCase() + "'");
-		return rs.next();
-	}
-
-	/**
-	 * Liefert eine Liste der Rollen in denen der Übergebenen USER (Login role)
-	 * ist. <br/>
-	 * Tested with PG 8.4
-	 */
-	public static List<String> listRolesForUser(Connection c, String username)
-			throws SQLException {
-		List<String> roles = new ArrayList<String>();
-		ResultSet rs = c
-				.createStatement()
-				.executeQuery(
-						"select rolname from pg_user join pg_auth_members on (pg_user.usesysid=pg_auth_members.member) join pg_roles on (pg_roles.oid=pg_auth_members.roleid) where pg_user.usename='"
-								+ username.toLowerCase() + "'");
-		while (rs.next()) {
-			roles.add(rs.getString(1));
-		}
-		return roles;
-	}
-
-	/**
-	 * Liefert alle Benutzer der DB zurück.
-	 * 
-	 * @throws SQLException
-	 */
-	public static List<String> listUsers(Connection c) throws SQLException {
-		List<String> roles = new ArrayList<String>();
-		ResultSet rs = c.createStatement()
-				.executeQuery("select * from pg_user");
-		while (rs.next()) {
-			roles.add(rs.getString(1));
-		}
-		return roles;
-	}
-
-	/**
-	 * Liste aller Tabellennamen in diesem Schema, ohne die Schemaangabe im
-	 * Namen. (Also 'anreden' und nicht 'public.anreden') <br/>
-	 * Tested with PG 8.4
-	 * 
-	 * @param schemaname
-	 *            if <code>null</code>, <code>public</code> is used.
-	 */
-	public static List<String> listTablesInSchema(Connection c,
-			String schemaname) throws SQLException {
-		List<String> tables = new ArrayList<String>();
-
-		String sql = "select tablename from pg_tables where schemaname = '"
-				+ schemaname.toLowerCase() + "'";
-		ResultSet rs = c.createStatement().executeQuery(sql);
-		while (rs.next()) {
-			tables.add(rs.getString(1));
-		}
-		return tables;
-	}
-
-	/**
-	 * Liefert <code>true</code> wenn der Benutzername im DBMS Superuser ist.
-	 */
-	public static boolean isSuperuser(Connection c, String username)
-			throws SQLException {
-		ResultSet rs = c.createStatement().executeQuery(
-				"select usesuper from pg_user where usename = '" + username
-						+ "' and usesuper = true");
-		if (rs.next()) {
-			return true;
-		}
-		return false;
-	}
-
-	public static boolean existsRole(Connection c, String rolename)
-			throws SQLException {
-		ResultSet rs = c.createStatement().executeQuery(
-				"select count(1) from pg_roles where rolname = '"
-						+ rolename.toLowerCase() + "'");
-		if (rs.next())
-			return rs.getInt(1) > 0;
-		return false;
-	}
-
-	public static void removeAllPrivilegesFrom(Connection c, String rolename,
-			String tablename) throws SQLException {
-		c.createStatement().executeUpdate(
-				"revoke all on TABLE " + tablename.toLowerCase() + " from "
-						+ rolename.toLowerCase() + " cascade");
-	}
-
-	/**
-	 * Löscht eine Rolle wenn sie vorher existiert
-	 */
-	public static void dropRoleIfExists(Connection c, String rolename)
-			throws SQLException {
-		c.createStatement().executeUpdate(
-				"drop role if exists " + rolename.toLowerCase());
-	}
-
-	/**
-	 * Löscht einen Trigger wenn er vorher existierte.
-	 * 
-	 * @param c
-	 * @param triggerName
-	 * @param tableName
-	 */
-	public static void dropTriggerIfExists(Connection c, String triggerName,
-			String tableName) throws SQLException {
-		c.createStatement().executeUpdate(
-				"drop TRIGGER if exists " + triggerName.toLowerCase() + " ON "
-						+ tableName);
-	}
-
-	/**
-	 * 
-	 * @param c
-	 * @param name
-	 *            z.B.: keckformel wird dann zu keckformel()
-	 * @param plCommands
-	 *            z.B. NEW.kpk_kreis =
-	 *            NEW.risiko_soz+NEW.risiko_emo+NEW.risiko_moti
-	 *            +NEW.risiko_spr+NEW.risiko_wohl;
-	 * @throws SQLException
-	 */
-	public static void createOrReplaceFunction(Connection c, String name,
-			String plCommands) throws SQLException {
-		// System.err.println(plCommands);
-		c.createStatement().executeUpdate(
-				"CREATE OR REPLACE FUNCTION " + name + "()"
-						+ "RETURNS trigger AS 'BEGIN " + plCommands
-						+ "RETURN NEW; END;' LANGUAGE 'plpgsql'");
-	}
-
-	/**
-	 * @param c
-	 * @param triggerName
-	 * @param type
-	 *            z.B. "BEFORE INSERT OR UPDATE"
-	 * @param tableName
-	 * @param plCommands
-	 *            Simple PSQL commands
-	 */
-	public static void createOrRecreateTrigger(Connection c,
-			String triggerName, String type, String tableName, String plCommands)
-			throws SQLException {
-		dropTriggerIfExists(c, triggerName, tableName);
-		createOrReplaceFunction(c, triggerName + "_fn", plCommands);
-		c.createStatement().executeUpdate(
-				"CREATE TRIGGER " + triggerName + " " + type + " ON "
-						+ tableName + " FOR EACH ROW EXECUTE PROCEDURE "
-						+ triggerName + "_fn" + "()");
-	}
-
-	/**
-	 * @param tableName
-	 *            e.g. 'inseratabfragen_kvps'
-	 * @param columns
-	 *            e.g. 'inseratabfrage_id'
-	 * @param idxNamePostfix
-	 *            e.g. 'idx1'
-	 * @param unique
-	 *            <code>true</code> if the columns are unique. A UNIQUE INDEX
-	 *            will be created.
-	 */
-	public static void addIndex(Connection c, final String tableName,
-			final String columns, String idxPostfix, final boolean unique)
-			throws SQLException {
-		addIndex(c, tableName, columns, idxPostfix, unique, null);
-	}
-
-	/**
-	 * Liefert eine Liste aller Indexnamen die für eine Tabelle existieren. Der
-	 * Tabellenname wird mit <code>like</code> verglichen, darf also
-	 * <code>%</code> enthalten.
-	 */
-	public static List<String> listIndexesForTable(Connection c,
-			String tableName) throws SQLException {
-		Statement s = c.createStatement();
-
-		List<String> idxes = new ArrayList<String>();
-
-		String sql = "select t.relname as table_name, i.relname as index_name, array_to_string(array_agg(a.attname), ', ') as column_names from pg_class t, pg_class i, pg_index ix, pg_attribute a where t.oid = ix.indrelid and i.oid = ix.indexrelid and a.attrelid = t.oid and a.attnum = ANY(ix.indkey) and t.relkind = 'r' and t.relname like '"
-				+ tableName
-				+ "' group by t.relname, i.relname order by t.relname, i.relname; ";
-
-		ResultSet rs = s.executeQuery(sql);
-		while (rs.next()) {
-			idxes.add(rs.getString(2));
-		}
-
-		return idxes;
-
-	}
-
-	/**
-	 * @param tableName
-	 *            e.g. 'inseratabfragen_kvps'
-	 * @param columns
-	 *            e.g. 'inseratabfrage_id'
-	 * @param idxNamePostfix
-	 *            e.g. 'idx1'
-	 * @param unique
-	 *            <code>true</code> if the columns are unique. A UNIQUE INDEX
-	 *            will be created.
-	 * @param tablespace
-	 *            <code>null</code> oder der name des tablespace in dem der
-	 *            Index liegen soll.
-	 */
-	public static void addIndex(Connection c, final String tableName,
-			final String columns, String idxPostfix, final boolean unique,
-			String tablespace) throws SQLException {
-		final String idxName = (tableName + "_" + idxPostfix).replace(".", "_");
-
-		for (String existIdxName : listIndexesForTable(c, tableName)) {
-			if (existIdxName.equals(idxName))
-				// Existiert bereits.
-				return;
-		}
-
-		Statement s = c.createStatement();
-
-		final String queryString = "CREATE " + (unique ? "UNIQUE " : "")
-				+ "INDEX " + idxName + " ON " + tableName + " (" + columns
-				+ ") "
-				+ (tablespace == null ? "" : " TABLESPACE " + tablespace);
-		try {
-			s.execute(queryString);
-			c.commit();
-			log.info("Neuen Index erstellt: " + queryString);
-		} catch (SQLException e) {
-			c.rollback();
-			Throwable cause = e;
-			if (e.getCause() != null)
-				cause = e.getCause();
-
-			// keine Ausgabe bei: already EXISTs, EXISTiert
-			// bereits,
-			// ...
-			// Ex abfangen, wenn IDX schon existiert
-
-			String msg = cause.getMessage();
-			if (msg.endsWith("already exists")
-					|| msg.endsWith("existiert bereits")) {
-				// TO NOTHING, IDX already exists
-				log.info("Index existierte bereits, nicht neuerstellt: "
-						+ queryString);
-			} else
-				log.error(e.getLocalizedMessage(), e);
-
-		}
-
-	}
-
-	/**
-	 * Fügt einen Benutzer zu einer Rolle hinzu. Wenn der benutzer bereits in
-	 * der Rolle enthalten ist, wird keine Exception geschmisssen.
-	 * 
-	 * @throws SQLException
-	 */
-	public static void grantRoleToUser(Connection c, String rolename,
-			String username) throws SQLException {
-		c.createStatement().executeUpdate(
-				"GRANT " + rolename + " TO " + username);
-	}
-
-}

Copied: trunk/schmitzm-core/src/main/java/de/schmitzm/postgres/PGUtil.java (from rev 1695, trunk/schmitzm-core/src/main/java/de/schmitzm/geotools/postgres/PGUtil.java)
===================================================================
--- trunk/schmitzm-core/src/main/java/de/schmitzm/geotools/postgres/PGUtil.java	2011-08-29 12:37:18 UTC (rev 1695)
+++ trunk/schmitzm-core/src/main/java/de/schmitzm/postgres/PGUtil.java	2011-08-29 13:05:14 UTC (rev 1696)
@@ -0,0 +1,447 @@
+package de.schmitzm.postgres;
+
+import java.sql.Connection;
+import java.sql.ResultSet;
+import java.sql.SQLException;
+import java.sql.Statement;
+import java.util.ArrayList;
+import java.util.List;
+
+import org.apache.log4j.Logger;
+
+import de.schmitzm.lang.LangUtil;
+
+/**
+ * Hilfsmethoden für PostgreSQL. Die Dependency soll nur {@link Connection}
+ * sein. In Hibernate kann über #doWork eine {@link Connection} erhalten werden.
+ */
+public class PGUtil {
+	static final Logger log = Logger.getLogger(PGUtil.class);
+
+	/**
+	 * PostgreSQL Privilegien die per Grant einer Tabelle zugeordnet werden
+	 * können.<br/>
+	 * 
+	 * @see http://www.postgresql.org/docs/9.1/static/sql-grant.html
+	 */
+	public enum Privileges {
+		SELECT, INSERT, UPDATE, DELETE, REFERENCES, TEMPORARY, ALL_PRIVILEGES(
+				"ALL PRIVILEGES");
+
+		String sql;
+
+		Privileges() {
+			this.sql = super.toString();
+		}
+
+		Privileges(String sql) {
+			this.sql = sql;
+		}
+
+		@Override
+		public String toString() {
+			return this.sql;
+		}
+	}
+
+	/**
+	 * Fügt Privilegien für eine Rolle einer Tabelle hinzu.
+	 * 
+	 * @param tablename
+	 *            Tabellennamen, optional mit "schema.tablename"
+	 * @param targetRole
+	 *            Darf PUBLIC sein, oder Name einer ROLLE.
+	 * @param privileges
+	 *            List der zuzuordnenden Privilegien
+	 * @throws SQLException
+	 */
+	public static void grantPrivilegesOnTable(Connection c, String targetRole,
+			String tablename, Privileges... privileges) throws SQLException {
+		// GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
+		String sql = "GRANT "
+				+ LangUtil.stringConcatWithSep(",", (Object[]) privileges)
+				+ " ON " + tablename + " TO " + targetRole;
+		c.createStatement().executeUpdate(sql);
+	}
+
+	/**
+	 * Entfernt Privilegien für eine Rolle von einre Tabelle.
+	 * 
+	 * @param tablename
+	 *            Tabellennamen, optional mit "schema.tablename"
+	 * @param privileges
+	 *            List der zuzuordnenden Privilegien
+	 * @throws SQLException
+	 */
+	public static void revokePrivilegesOnTable(Connection c, String tablename,
+			String targetRole, Privileges... privileges) throws SQLException {
+		// GRANT SELECT, UPDATE, INSERT ON mytable TO admin;
+		String sql = "REVOKE "
+				+ LangUtil.stringConcatWithSep(",", (Object[]) privileges)
+				+ " ON " + tablename + " FROM " + targetRole;
+		c.createStatement().executeUpdate(sql);
+	}
+
+	/**
+	 * Erstellt eine neue Rolle
+	 */
+	public static void createRole(Connection c, String rolename)
+			throws SQLException {
+		String sql = "CREATE ROLE " + rolename;
+		c.createStatement().executeUpdate(sql);
+	}
+
+	/**
+	 * Querys the <code>geometry_columns</code> table is part of every POSTGIS
+	 * installation and must/should describe the geometry columns and tables.
+	 */
+	static public String[] getColumnsDescribedInGeometryColumnsTable(Statement s) {
+		String[] columns = new String[0];
+		try {
+			ResultSet askGeoe = s
+					.executeQuery("SELECT f_table_name FROM geometry_columns;");
+			while (askGeoe.next()) {
+				columns = LangUtil.extendArray(columns, askGeoe.getString(1));
+			}
+		} catch (SQLException e) {
+			log.error(e, e);
+		}
+
+		return columns;
+
+	}
+
+	/**
+	 * Creates or Updates
+	 * 
+	 * @param tableName
+	 * @param geoColumnName
+	 * @param srid
+	 */
+	@Deprecated
+	// tut noch nicht
+	public static void createOrUpdateGeometrysColumnsEntry(String tableName,
+			String geoColumnName, int srid) {
+
+		String createGeometryEntrySQL = "INSERT INTO geometry_columns (f_table_catalog, f_table_schema, f_table_name, f_geometry_column, coord_dimension, srid, \"type\") VALUES ( '', 'public', '"
+				+ tableName
+				+ "', '"
+				+ geoColumnName
+				+ "', 2, "
+				+ srid
+				+ ",'MULTIPOLYGON' ) LIMIT 1;";
+	}
+
+	// TODO isGeoColumn();
+
+	/**
+	 * @param binding
+	 *            Eine "einfache" Javaklasse, die in PG abgebildet werden soll.
+	 * @return einen PG-spezifischen Datentypenamen für einen Javatyp zurück,
+	 *         z.b. "double precision" für <code>Double.class</code>
+	 */
+	public static String getColTypeName(Class<?> binding) {
+
+		if (binding.isAssignableFrom(Double.class)) {
+			return "double precision"; // eg 'number' at oracle
+		} else if (binding.isAssignableFrom(String.class)) {
+			return "text";
+		} else if (binding.isAssignableFrom(Integer.class)) {
+			return "integer";
+		} else if (binding.isAssignableFrom(Long.class)) {
+			return "bigint";
+		}
+
+		throw new RuntimeException("DB Type mapping for " + binding
+				+ " not yet implemented.");
+	}
+
+	/**
+	 * Legt ein Schema an, wenn es vorher nicht existierte.
+	 * 
+	 * @return <code>true</code> wenn das Schema neu angelegt wurde.
+	 */
+	public static boolean createSchemaIfNotExists(Connection c,
+			String schemaname) throws SQLException {
+		if (!existsSchema(c, schemaname)) {
+			c.createStatement().execute(
+					"create schema " + schemaname.toLowerCase());
+			return true;
+		}
+		return false;
+	}
+
+	/**
+	 * Liefert <code>true</code> wenn ein Schema mit dem Namen in der PG
+	 * Datenbank existiert.
+	 */
+	public static boolean existsSchema(Connection c, String schemaname)
+			throws SQLException {
+		ResultSet rs = c.createStatement().executeQuery(
+				"select 1 from pg_catalog.pg_namespace where nspname = '"
+						+ schemaname.toLowerCase() + "'");
+		return rs.next();
+	}
+
+	/**
+	 * Liefert eine Liste der Rollen in denen der Übergebenen USER (Login role)
+	 * ist. <br/>
+	 * Tested with PG 8.4
+	 */
+	public static List<String> listRolesForUser(Connection c, String username)
+			throws SQLException {
+		List<String> roles = new ArrayList<String>();
+		ResultSet rs = c
+				.createStatement()
+				.executeQuery(
+						"select rolname from pg_user join pg_auth_members on (pg_user.usesysid=pg_auth_members.member) join pg_roles on (pg_roles.oid=pg_auth_members.roleid) where pg_user.usename='"
+								+ username.toLowerCase() + "'");
+		while (rs.next()) {
+			roles.add(rs.getString(1));
+		}
+		return roles;
+	}
+
+	/**
+	 * Liefert alle Benutzer der DB zurück.
+	 * 
+	 * @throws SQLException
+	 */
+	public static List<String> listUsers(Connection c) throws SQLException {
+		List<String> roles = new ArrayList<String>();
+		ResultSet rs = c.createStatement()
+				.executeQuery("select * from pg_user");
+		while (rs.next()) {
+			roles.add(rs.getString(1));
+		}
+		return roles;
+	}
+
+	/**
+	 * Liste aller Tabellennamen in diesem Schema, ohne die Schemaangabe im
+	 * Namen. (Also 'anreden' und nicht 'public.anreden') <br/>
+	 * Tested with PG 8.4
+	 * 
+	 * @param schemaname
+	 *            if <code>null</code>, <code>public</code> is used.
+	 */
+	public static List<String> listTablesInSchema(Connection c,
+			String schemaname) throws SQLException {
+		List<String> tables = new ArrayList<String>();
+
+		String sql = "select tablename from pg_tables where schemaname = '"
+				+ schemaname.toLowerCase() + "'";
+		ResultSet rs = c.createStatement().executeQuery(sql);
+		while (rs.next()) {
+			tables.add(rs.getString(1));
+		}
+		return tables;
+	}
+
+	/**
+	 * Liefert <code>true</code> wenn der Benutzername im DBMS Superuser ist.
+	 */
+	public static boolean isSuperuser(Connection c, String username)
+			throws SQLException {
+		ResultSet rs = c.createStatement().executeQuery(
+				"select usesuper from pg_user where usename = '" + username
+						+ "' and usesuper = true");
+		if (rs.next()) {
+			return true;
+		}
+		return false;
+	}
+
+	public static boolean existsRole(Connection c, String rolename)
+			throws SQLException {
+		ResultSet rs = c.createStatement().executeQuery(
+				"select count(1) from pg_roles where rolname = '"
+						+ rolename.toLowerCase() + "'");
+		if (rs.next())
+			return rs.getInt(1) > 0;
+		return false;
+	}
+
+	public static void removeAllPrivilegesFrom(Connection c, String rolename,
+			String tablename) throws SQLException {
+		c.createStatement().executeUpdate(
+				"revoke all on TABLE " + tablename.toLowerCase() + " from "
+						+ rolename.toLowerCase() + " cascade");
+	}
+
+	/**
+	 * Löscht eine Rolle wenn sie vorher existiert
+	 */
+	public static void dropRoleIfExists(Connection c, String rolename)
+			throws SQLException {
+		c.createStatement().executeUpdate(
+				"drop role if exists " + rolename.toLowerCase());
+	}
+
+	/**
+	 * Löscht einen Trigger wenn er vorher existierte.
+	 * 
+	 * @param c
+	 * @param triggerName
+	 * @param tableName
+	 */
+	public static void dropTriggerIfExists(Connection c, String triggerName,
+			String tableName) throws SQLException {
+		c.createStatement().executeUpdate(
+				"drop TRIGGER if exists " + triggerName.toLowerCase() + " ON "
+						+ tableName);
+	}
+
+	/**
+	 * 
+	 * @param c
+	 * @param name
+	 *            z.B.: keckformel wird dann zu keckformel()
+	 * @param plCommands
+	 *            z.B. NEW.kpk_kreis =
+	 *            NEW.risiko_soz+NEW.risiko_emo+NEW.risiko_moti
+	 *            +NEW.risiko_spr+NEW.risiko_wohl;
+	 * @throws SQLException
+	 */
+	public static void createOrReplaceFunction(Connection c, String name,
+			String plCommands) throws SQLException {
+		// System.err.println(plCommands);
+		c.createStatement().executeUpdate(
+				"CREATE OR REPLACE FUNCTION " + name + "()"
+						+ "RETURNS trigger AS 'BEGIN " + plCommands
+						+ "RETURN NEW; END;' LANGUAGE 'plpgsql'");
+	}
+
+	/**
+	 * @param c
+	 * @param triggerName
+	 * @param type
+	 *            z.B. "BEFORE INSERT OR UPDATE"
+	 * @param tableName
+	 * @param plCommands
+	 *            Simple PSQL commands
+	 */
+	public static void createOrRecreateTrigger(Connection c,
+			String triggerName, String type, String tableName, String plCommands)
+			throws SQLException {
+		dropTriggerIfExists(c, triggerName, tableName);
+		createOrReplaceFunction(c, triggerName + "_fn", plCommands);
+		c.createStatement().executeUpdate(
+				"CREATE TRIGGER " + triggerName + " " + type + " ON "
+						+ tableName + " FOR EACH ROW EXECUTE PROCEDURE "
+						+ triggerName + "_fn" + "()");
+	}
+
+	/**
+	 * @param tableName
+	 *            e.g. 'inseratabfragen_kvps'
+	 * @param columns
+	 *            e.g. 'inseratabfrage_id'
+	 * @param idxNamePostfix
+	 *            e.g. 'idx1'
+	 * @param unique
+	 *            <code>true</code> if the columns are unique. A UNIQUE INDEX
+	 *            will be created.
+	 */
+	public static void addIndex(Connection c, final String tableName,
+			final String columns, String idxPostfix, final boolean unique)
+			throws SQLException {
+		addIndex(c, tableName, columns, idxPostfix, unique, null);
+	}
+
+	/**
+	 * Liefert eine Liste aller Indexnamen die für eine Tabelle existieren. Der
+	 * Tabellenname wird mit <code>like</code> verglichen, darf also
+	 * <code>%</code> enthalten.
+	 */
+	public static List<String> listIndexesForTable(Connection c,
+			String tableName) throws SQLException {
+		Statement s = c.createStatement();
+
+		List<String> idxes = new ArrayList<String>();
+
+		String sql = "select t.relname as table_name, i.relname as index_name, array_to_string(array_agg(a.attname), ', ') as column_names from pg_class t, pg_class i, pg_index ix, pg_attribute a where t.oid = ix.indrelid and i.oid = ix.indexrelid and a.attrelid = t.oid and a.attnum = ANY(ix.indkey) and t.relkind = 'r' and t.relname like '"
+				+ tableName
+				+ "' group by t.relname, i.relname order by t.relname, i.relname; ";
+
+		ResultSet rs = s.executeQuery(sql);
+		while (rs.next()) {
+			idxes.add(rs.getString(2));
+		}
+
+		return idxes;
+
+	}
+
+	/**
+	 * @param tableName
+	 *            e.g. 'inseratabfragen_kvps'
+	 * @param columns
+	 *            e.g. 'inseratabfrage_id'
+	 * @param idxNamePostfix
+	 *            e.g. 'idx1'
+	 * @param unique
+	 *            <code>true</code> if the columns are unique. A UNIQUE INDEX
+	 *            will be created.
+	 * @param tablespace
+	 *            <code>null</code> oder der name des tablespace in dem der
+	 *            Index liegen soll.
+	 */
+	public static void addIndex(Connection c, final String tableName,
+			final String columns, String idxPostfix, final boolean unique,
+			String tablespace) throws SQLException {
+		final String idxName = (tableName + "_" + idxPostfix).replace(".", "_");
+
+		for (String existIdxName : listIndexesForTable(c, tableName)) {
+			if (existIdxName.equals(idxName))
+				// Existiert bereits.
+				return;
+		}
+
+		Statement s = c.createStatement();
+
+		final String queryString = "CREATE " + (unique ? "UNIQUE " : "")
+				+ "INDEX " + idxName + " ON " + tableName + " (" + columns
+				+ ") "
+				+ (tablespace == null ? "" : " TABLESPACE " + tablespace);
+		try {
+			s.execute(queryString);
+			c.commit();
+			log.info("Neuen Index erstellt: " + queryString);
+		} catch (SQLException e) {
+			c.rollback();
+			Throwable cause = e;
+			if (e.getCause() != null)
+				cause = e.getCause();
+
+			// keine Ausgabe bei: already EXISTs, EXISTiert
+			// bereits,
+			// ...
+			// Ex abfangen, wenn IDX schon existiert
+
+			String msg = cause.getMessage();
+			if (msg.endsWith("already exists")
+					|| msg.endsWith("existiert bereits")) {
+				// TO NOTHING, IDX already exists
+				log.info("Index existierte bereits, nicht neuerstellt: "
+						+ queryString);
+			} else
+				log.error(e.getLocalizedMessage(), e);
+
+		}
+
+	}
+
+	/**
+	 * Fügt einen Benutzer zu einer Rolle hinzu. Wenn der benutzer bereits in
+	 * der Rolle enthalten ist, wird keine Exception geschmisssen.
+	 * 
+	 * @throws SQLException
+	 */
+	public static void grantRoleToUser(Connection c, String rolename,
+			String username) throws SQLException {
+		c.createStatement().executeUpdate(
+				"GRANT " + rolename + " TO " + username);
+	}
+
+}


Property changes on: trunk/schmitzm-core/src/main/java/de/schmitzm/postgres/PGUtil.java
___________________________________________________________________
Name: svn:mime-type
   + text/plain

Modified: trunk/schmitzm-gt/src/main/java/de/schmitzm/geotools/postgres/PGUtilGT.java
===================================================================
--- trunk/schmitzm-gt/src/main/java/de/schmitzm/geotools/postgres/PGUtilGT.java	2011-08-29 12:37:18 UTC (rev 1695)
+++ trunk/schmitzm-gt/src/main/java/de/schmitzm/geotools/postgres/PGUtilGT.java	2011-08-29 13:05:14 UTC (rev 1696)
@@ -3,6 +3,8 @@
 import org.apache.log4j.Logger;
 import org.opengis.referencing.crs.CoordinateReferenceSystem;
 
+import de.schmitzm.postgres.PGUtil;
+
 /**
  * Hilfsmethoden für PostgreSQL
  */



More information about the Schmitzm-commits mailing list