dblink Functions

    Greenplum Database supports dblink connections between databases in Greenplum Database installations with the same major version number. dblink may also connect to other Greenplum Database installations that use compatible libpq libraries.

    You create a dblink connection to a database and execute an SQL command in the database as a Greenplum Database user. The user must have the appropriate access privileges to the database tables referenced in the SQL command. If the database is in a remote system, the user must be defined as a Greenplum Database user in the remote system with the appropriate access privileges.

    dblink is intended for database users to perform short ad hoc queries in other databases. dblink is not intended for use as a replacement for external tables or for administrative tools such as gpcopy or gptransfer (deprecated).

    Refer to dblink in the PostgreSQL documentation for more information about individual dblink functions.

    Parent topic:

    In this release of Greenplum Database, statements that modify table data cannot use named or implicit dblink connections. Instead, you must provide the connection string directly in the dblink() function. For example:

    The Greenplum Database version of dblink deactivates the following asynchronous functions:

    • dblink_send_query()
    • dblink_is_busy()
    • dblink_get_result()

    The following procedure identifies the basic steps for configuring and using dblink in Greenplum Database. The examples use dblink_connect() to create a connection to a database and dblink() to execute an SQL query.

    1. Begin by creating a sample table to query using the dblink functions. These commands create a small table in the postgres database, which you will later query from the testdb database using dblink:

      1. $ psql -d postgres
      2. psql (8.3.23)
      3. Type "help" for help.
      4. postgres=# CREATE TABLE testdblink (a int, b text) DISTRIBUTED BY (a);
      5. CREATE TABLE
      6. INSERT 0 2
      7. postgres=# **\\q
      8. **$
    2. Log into a different database as a superuser. In this example, the superuser gpadmin logs into the database testdb. If the functions are not already available, install them using the $GPHOME/share/postgresql/contrib/dblink.sql script:

      1. $ psql -d testdb
      2. psql (9.4beta1)
      3. Type "help" for help.
      4. testdb=# i /usr/local/greenplum-db/share/postgresql/contrib/dblink.sql
      5. SET
      6. CREATE FUNCTION
      7. CREATE FUNCTION
      8. ...
    3. Use the dblink_connect() function to create either an implicit or a named connection to another database. The connection string that you provide should be a libpq-style keyword/value string. This example creates a connection named mylocalconn to the postgres database on the local Greenplum Database system:

      1. dblink_connect
      2. ----------------
      3. OK
      4. (1 row)

      Note: If a user is not specified, dblink_connect() uses the value of the PGUSER environment variable when Greenplum Database was started. If PGUSER is not set, the default is the system user that started Greenplum Database.

    4. Use the dblink() function to query a database using a configured connection. Keep in mind that this function returns a record type, so you must assign the columns returned in the dblink() query. For example, the following command uses the named connection to query the table you created earlier:

    To connect to the local database as another user, specify the user in the connection string. This example connects to the database as the user test_user. Using dblink_connect(), a superuser can create a connection to another local database without specifying a password.

    1. testdb=# SELECT dblink_connect('localconn2', 'dbname=postgres user=test_user');

    To make a connection to a remote database system, include host and password information in the connection string. For example, to create an implicit dblink connection to a remote system:

    1. testdb=# SELECT dblink_connect('host=remotehost port=5432 dbname=postgres user=gpadmin password=secret');

    To make a connection to a database with dblink_connect(), non-superusers must include host, user, and password information in the connection string. The host, user, and password information must be included even when connecting to a local database. For example, the user test_user can create a dblink connection to the local system mdw with this command:

    1. testdb=> SELECT dblink_connect('host=mdw port=5432 dbname=postgres user=test_user password=secret');

    In some situations, it may be appropriate to grant EXECUTE permission on dblink_connect_u() to specific users who are considered trustworthy, but this should be done with care.

    Warning: If a Greenplum Database system has configured users with an authentication method that does not involve a password, then impersonation and subsequent escalation of privileges can occur when a non-superuser executes dblink_connect_u(). The dblink connection will appear to have originated from the user specified by the function. For example, a non-superuser can execute dblink_connect_u() and specify a user that is configured with trust authentication.

    Also, even if the dblink connection requires a password, it is possible for the password to be supplied from the server environment, such as a ~/.pgpass file belonging to the server’s user.

    1. As a superuser, grant the EXECUTE privilege on the dblink_connect_u() functions in the user database. This example grants the privilege to the non-superuser test_user on the functions with the signatures for creating an implicit or a named dblink connection.

    2. Now test_user can create a connection to another local database without a password. For example, test_user can log into the testdb database and execute this command to create a connection named testconn to the local postgres database.

      1. testdb=> SELECT dblink_connect_u('testconn', 'dbname=postgres user=test_user');

      Note: If a user is not specified, dblink_connect_u() uses the value of the PGUSER environment variable when Greenplum Database was started. If PGUSER is not set, the default is the system user that started Greenplum Database.

    3. test_user can use the dblink() function to execute a query using a dblink connection. For example, this command uses the dblink connection named testconn created in the previous step. test_user must have appropriate access to the table.

      1. testdb=> SELECT * FROM dblink('testconn', 'SELECT * FROM testdblink') AS dbltab(id int, product text);

    When you use dblink to connect to Greenplum Database over an encrypted connection, you must specify the sslmode property in the connection string. Set sslmode to at least require to disallow unencrypted transfers. For example:

    1. testdb=# SELECT dblink_connect('greenplum_con_sales', 'dbname=sales host=gpmaster user=gpadmin sslmode=require');