Skip to content
This repository has been archived by the owner on Jul 11, 2022. It is now read-only.

Commit

Permalink
[BZ 1381720] Add ability to clean orphaned large objects from the dat…
Browse files Browse the repository at this point in the history
…abase

Query pg_largeobject_metadata when used with Postgres >= 9.0
  • Loading branch information
Michael Burman authored and Simeon Pinder committed Jan 13, 2017
1 parent 248bca5 commit 8d7ec5d
Show file tree
Hide file tree
Showing 3 changed files with 108 additions and 6 deletions.
Expand Up @@ -19,18 +19,14 @@

package org.rhq.plugins.postgres;

import static org.rhq.core.domain.measurement.AvailabilityType.DOWN;
import static org.rhq.core.domain.measurement.AvailabilityType.UP;
import static org.rhq.core.domain.resource.CreateResourceStatus.FAILURE;
import static org.rhq.core.domain.resource.CreateResourceStatus.SUCCESS;
import static org.rhq.plugins.postgres.PostgresDiscoveryComponent.buildConnection;

import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.ResultSetMetaData;
import java.sql.SQLException;
import java.sql.Statement;
import java.util.ArrayList;
import java.util.List;
import java.util.Set;

import org.apache.commons.logging.Log;
Expand All @@ -56,6 +52,12 @@
import org.rhq.plugins.database.DatabasePluginUtil;
import org.rhq.plugins.database.PooledConnectionProvider;

import static org.rhq.core.domain.measurement.AvailabilityType.DOWN;
import static org.rhq.core.domain.measurement.AvailabilityType.UP;
import static org.rhq.core.domain.resource.CreateResourceStatus.FAILURE;
import static org.rhq.core.domain.resource.CreateResourceStatus.SUCCESS;
import static org.rhq.plugins.postgres.PostgresDiscoveryComponent.buildConnection;

public class PostgresDatabaseComponent implements DatabaseComponent<PostgresServerComponent<?>>,
ConnectionPoolingSupport, MeasurementFacet, CreateChildResourceFacet, OperationFacet {

Expand Down Expand Up @@ -262,6 +264,8 @@ public OperationResult invokeOperation(String name, Configuration parameters) th
return resetStatistics();
} else if ("invokeSql".equals(name)) {
return invokeSql(parameters);
} else if ("vacuumlo".equals(name)) {
return vacuumLo();
} else {
throw new UnsupportedOperationException("Operation [" + name + "] is not supported yet.");
}
Expand Down Expand Up @@ -342,4 +346,91 @@ private OperationResult invokeSql(Configuration parameters) throws SQLException
}
}

/**
* This functionality is a port of vacuumlo tool in the Postgres distribution
*
* @return OperationResult
*/
private OperationResult vacuumLo() {
Connection c = null;
Statement clearVacuumL = null;
Statement unlinkStatement = null;
ResultSet rs = null;
try {
c = getPooledConnectionProvider().getPooledConnection();
StringBuilder b = new StringBuilder();
b.append("CREATE TEMP TABLE vacuum_l AS (");

if(postgresServerComponent.isVersionGreaterThanOrEqualTo90(c)) {
b.append("SELECT oid AS lo FROM pg_largeobject_metadata");
} else {
b.append("SELECT DISTINCT loid AS lo FROM pg_largeobject");
}

b.append(")");
PreparedStatement tempTable = c.prepareStatement(b.toString());
tempTable.execute();

PreparedStatement tablesPs = c.prepareStatement("SELECT s.nspname, c.relname, a.attname\n" +
"FROM pg_class c, pg_attribute a, pg_namespace s, pg_type t\n" +
"WHERE a.attnum > 0 AND NOT a.attisdropped\n" +
" AND a.attrelid = c.oid\n" +
" AND a.atttypid = t.oid\n" +
" AND c.relnamespace = s.oid\n" +
" AND t.typname in ('oid', 'lo')\n" +
" AND c.relkind in ('r', 'm')\n" +
" AND s.nspname !~ '^pg_'");
rs = tablesPs.executeQuery();

// Postgres JDBC driver can't handle this as PreparedStatement
clearVacuumL = c.createStatement();

while (rs.next()) {
String schemaName = rs.getString(1);
String tableName = rs.getString(2);
String columnName = rs.getString(3);

String sql = String.format("DELETE FROM vacuum_l WHERE lo IN (SELECT %s FROM %s.%s)", columnName,
schemaName, tableName);

clearVacuumL.execute(sql);
}
rs.close();

int cleanCount = 0;

// We can't delete everything at once or Postgres might run out of shared memory for locks
PreparedStatement deletedOids = c.prepareStatement("SELECT lo FROM vacuum_l");
rs = deletedOids.executeQuery();

List<Integer> oidsToDelete = new ArrayList<Integer>();

while (rs.next()) {
oidsToDelete.add(rs.getInt(1));
}
rs.close();

// PostgreSQL can't handle this as PreparedStatement either
unlinkStatement = c.createStatement();
String unlinkSQLProto = "SELECT lo_unlink(%s)";

for (int i = 0; i < oidsToDelete.size(); i++) {
String sqlUnlink = String.format(unlinkSQLProto, oidsToDelete.get(i));
unlinkStatement.execute(sqlUnlink);
cleanCount++;
}

OperationResult result = new OperationResult();
result.getComplexResults().put(new PropertySimple("result", "Query removed " + cleanCount + " orphan large objects"));
return result;
} catch (SQLException e) {
OperationResult result = new OperationResult("Failed to delete orphaned objects");
result.setErrorMessage(e.getMessage());
return result;
} finally {
DatabasePluginUtil.safeClose(unlinkStatement);
DatabasePluginUtil.safeClose(c, clearVacuumL, rs);
}
}

}
Expand Up @@ -619,4 +619,9 @@ boolean isVersionGreaterThan92(Connection connection) throws SQLException {
return metaData.getDatabaseMajorVersion() >= 9 && metaData.getDatabaseMinorVersion() >= 2;
}

boolean isVersionGreaterThanOrEqualTo90(Connection connection) throws SQLException {
DatabaseMetaData metaData = connection.getMetaData();
return metaData.getDatabaseMajorVersion() >= 9;
}

}
Expand Up @@ -485,6 +485,12 @@
</results>
</operation>

<operation name="vacuumlo" displayName="Remove orphan large objects" description="Removes orphaned large objects from pg_largeobject">
<results>
<c:simple-property name="result"/>
</results>
</operation>

<metric displayName="Backends" property="numbackends"
description="Number of active server processes for database"/>
<metric displayName="Transactions Committed" property="xact_commit" measurementType="trendsup" displayType="summary"
Expand Down

0 comments on commit 8d7ec5d

Please sign in to comment.