Okay, after setting up a hosting environment based on my original post, we immediately discovered a few caveats. One is that, as written, pg_user creates issues with pg_dump because a given user needs access to various system catalogs and postgres must exist in pg_user, so we updated the view. Secondly, though, we actually had to modify system_views.sql because pg_user, as a system catalog, behaves differently from a standard view and caused more issues with pg_dump. So here's what we added to system_views.sql: CREATE VIEW pg_user AS SELECT usename, usesysid, usecreatedb, usesuper, usecatupd, '********'::text as passwd, valuntil, useconfig FROM pg_shadow WHERE usename IN ( (SELECT current_user), ( SELECT ps.usename FROM pg_database pd,pg_shadow ps WHERE pd.datdba=ps.usesysid AND datname=current_database() ), 'postgres' ) Then we ran into the problem of allowing users to dump their own databases, which requires access to pg_database that we're trying to prevent at the user level. So we're now setting our schema search path for all user-created databases to public, pg_catalog, $user. Then we're creating a view called pg_database as: CREATE OR REPLACE VIEW pg_db AS SELECT oid, * FROM pg_database WHERE datname=(select current_user) Now pg_dump should be able to use our restricted version of pg_database with little trouble, although I don't know (yet) whether putting a customized replacement view in front of an actual system catalog in the search path is going to cause any other issues in other parts of the system. So, to summarize: we're shooting for a user-isolated PostgreSQL hosting environment. In order to accomplish this, we have to hack the following: 1. system_views.sql 2. phpPgAdmin to use the custom pg_grp view (we could probably perform similar surgery to overshadow pg_group as we did pg_database with a view in public) Then we use the built in PostgreSQL privilege system as outlined in my original post plus modify the schema search path per user database. At the end of this, it seems like the only hobble (other than having to hack stuff to achieve user isolation) is that we can no longer get a list of users as super-user from pg_user. A couple of years ago, Tom Lane said this with regard to isolating users for a PostgreSQL-based hosting environment: But to me, that seems like a fairly draconian approach to creating a hosting environment. In MySQL, the hack is a privilege called SHOW DATABASES, which can be set for all databases. Their user setup seems to be wholly different because they don't seem to provide a cluster-wide mechanism for viewing users. Again, I'm wondering whether anyone else in the community has developed any best practices when it comes to PostgreSQL hosting. -- Thomas F. O'Connell Co-Founder, Information Architect Sitening, LLC Strategic Open Source: Open Your i™ 110 30th Avenue North, Suite 6 Nashville, TN 37203-6320 615-260-0005 On Jul 1, 2005, at 3:45 PM, Thomas F. O'Connell wrote:
|