Обсуждение: strange java query behaviour
Hi,
I've got a quite strange situation. Below is a simple test
@Test
public void test() throws SQLException {
String query1 = "SELECT * FROM information_schema.schemata WHERE schema_name = ?";
String query2 = "SELECT * FROM pg_catalog.pg_namespace where nspname = ?";
check(query1, "1", "public");
check(query2, "2", "public");
}
private void check(final String query, final String info, final String param) throws SQLException {
PreparedStatement stmt = connection.prepareStatement(query);
stmt.setString(1, param);
ResultSet schemas = stmt.executeQuery();
boolean exists = schemas.next();
System.out.println(info + " : " + exists);
}
The output is:
1 : false
2 : true
When I query the database using psql, both queries return sensible data (even when I prepare statements in postgres).
I'd like to use information_schema rather than using pg_catalog.
ENV:
Ubuntu 11.10
PostgreSQL 9.0.4 on x86_64-unknown-linux-gnu, compiled by GCC gcc (GCC) 4.1.2 20080704 (Red Hat 4.1.2-46), 64-bit
java version "1.6.0_26"
Java(TM) SE Runtime Environment (build 1.6.0_26-b03)
Java HotSpot(TM) 64-Bit Server VM (build 20.1-b02, mixed mode)
9.0-801.jdbc4
regards
Szymon
On Mon, Oct 24, 2011 at 23:23, Szymon Guz <mabewlun@gmail.com> wrote: > String query1 = "SELECT * FROM information_schema.schemata WHERE schema_name = ?"; > When I query the database using psql, both queries return sensible data > (even when I prepare statements in postgres). > I'd like to use information_schema rather than using pg_catalog. The documentation says: The view schemata contains all schemas in the current database that are owned by a currently enabled role. In other words: this view only displays schemas that are *owned* by your user, or roles that your current user inherits from (superuser sees everything of course). Sadly it doesn't list visible/accessible schemas. I think this is pretty surprising; not sure if it's just bad legacy or if there is some good reason for this behavior. I couldn't find any justification in the source code. I think we should add a TODO item for fixing this? Regards, Marti
On 25 October 2011 17:04, Marti Raudsepp <marti@juffo.org> wrote:
On Mon, Oct 24, 2011 at 23:23, Szymon Guz <mabewlun@gmail.com> wrote:
> String query1 = "SELECT * FROM information_schema.schemata WHERE schema_name = ?";> When I query the database using psql, both queries return sensible dataThe documentation says: The view schemata contains all schemas in the
> (even when I prepare statements in postgres).
> I'd like to use information_schema rather than using pg_catalog.
current database that are owned by a currently enabled role.
In other words: this view only displays schemas that are *owned* by
your user, or roles that your current user inherits from (superuser
sees everything of course). Sadly it doesn't list visible/accessible
schemas.
I think this is pretty surprising; not sure if it's just bad legacy or
if there is some good reason for this behavior. I couldn't find any
justification in the source code.
I think we should add a TODO item for fixing this?
Regards,
Marti
Hi,
thanks for the answer. I was really my fault: I've been using user test in the java test and postgres user in psql. I've changed the user to
postgres in java and results are OK now.
regards
Szymon
Marti Raudsepp <marti@juffo.org> writes:
> The documentation says: The view schemata contains all schemas in the
> current database that are owned by a currently enabled role.
> In other words: this view only displays schemas that are *owned* by
> your user, or roles that your current user inherits from (superuser
> sees everything of course). Sadly it doesn't list visible/accessible
> schemas.
> I think this is pretty surprising; not sure if it's just bad legacy or
> if there is some good reason for this behavior. I couldn't find any
> justification in the source code.
The justification is that the SQL standard requires the view to act that
way.
20.46 SCHEMATA view
Function
Identify the schemata in a catalog that are owned by a given user.
Definition
CREATE VIEW SCHEMATA AS
SELECT CATALOG_NAME, SCHEMA_NAME, SCHEMA_OWNER,
DEFAULT_CHARACTER_SET_CATALOG, DEFAULT_CHARACTER_SET_
SCHEMA,
DEFAULT_CHARACTER_SET_NAME, SQL_PATH
FROM DEFINITION_SCHEMA.SCHEMATA
WHERE ( SCHEMA_OWNER = CURRENT_USER
OR
SCHEMA_OWNER IN
( SELECT ROLE_NAME
FROM ENABLED_ROLES ) )
AND
CATALOG_NAME
= ( SELECT CATALOG_NAME
FROM INFORMATION_SCHEMA_CATALOG_NAME );
GRANT SELECT ON TABLE SCHEMATA
TO PUBLIC WITH GRANT OPTION;
> I think we should add a TODO item for fixing this?
Waste of breath. You could try lobbying the SQL committee to change the
standard, perhaps.
regards, tom lane