In the syntax CREATE FOREIGN TABLE (SQL on Hadoop or OBS) for creating a foreign table, you need to specify a foreign server associated with the MRS data source connection.
When you create an MRS data source connection on the GaussDB(DWS) management console, the database administrator dbadmin automatically creates a foreign server in the default database postgres. If you want to create a foreign table in the default database postgres to read MRS data, skip this section.
To allow a common user to create a foreign table in a user-defined database to read MRS data, you must manually create a foreign server in the user-defined database. This section describes how does a common user create a foreign server in a user-defined database. The procedure is as follows:
For details, see "Managing MRS Data Sources > Creating an MRS Data Source Connection" in the Data Warehouse Service User Guide.
If you no longer need to read data from the MRS data source and have deleted the MRS data source on the GaussDB(DWS) management console, only the foreign server automatically created in the default database gaussdb will be deleted, and the manually created foreign server needs to be deleted manually. For details about the deletion, see Deleting the Manually Created Foreign Server.
In the following example, a common user dbuser and a database mydatabase are created. Then, an administrator is used to grant foreign table permissions to user dbuser.
For example, use the gsql client to connect to the database by running the following command:
gsql -d postgres -h 192.168.2.30 -U dbadmin -p 8000 -W password -r
Enter your password as prompted.
Create a user named dbuser that has the permission to create databases.
CREATE USER dbuser WITH CREATEDB PASSWORD 'password';
SET ROLE dbuser PASSWORD 'password';
CREATE DATABASE mydatabase;
Query the database.
SELECT * FROM pg_database;
The database is successfully created if the returned result contains information about mydatabase.
datname | datdba | encoding | datcollate | datctype | datistemplate | datallowconn | datconnlimit | datlastsysoid | datfrozenxid | dattablespace | datcompatibility | datacl ------------+--------+----------+------------+----------+---------------+--------------+--------------+---------------+--------------+---------------+------------------+-------------------------------------- -------------- template1 | 10 | 0 | C | C | t | t | -1 | 14146 | 1351 | 1663 | ORA | {=c/Ruby,omm=CTc/Ruby} template0 | 10 | 0 | C | C | t | f | -1 | 14146 | 1350 | 1663 | ORA | {=c/Ruby,Ruby=CTc/Ruby} postgres | 10 | 0 | C | C | f | t | -1 | 14146 | 1352 | 1663 | ORA | {=Tc/Ruby,Ruby=CTc/Ruby,chaojun=C/Ruby,hu obinru=C/Ruby} mydatabase | 17000 | 0 | C | C | f | t | -1 | 14146 | 1351 | 1663 | ORA | (4 rows)
Use the connection to create a database as a database administrator.
\c mydatabase dbadmin;
Enter the password as prompted.
Note that you must use the administrator account to connect to the database where a foreign server is to be created and foreign tables are used; and then grant permissions to the common user.
GRANT ALL ON FOREIGN DATA WRAPPER hdfs_fdw TO dbuser;
The name of FOREIGN DATA WRAPPER must be hdfs_fdw. dbuser is the username for creating SERVER.
Run the following command to grant the user the permission to use foreign tables:
ALTER USER dbuser USEFT;
Query for the user.
SELECT r.rolname, r.rolsuper, r.rolinherit, r.rolcreaterole, r.rolcreatedb, r.rolcanlogin, r.rolconnlimit, r.rolvalidbegin, r.rolvaliduntil, ARRAY(SELECT b.rolname FROM pg_catalog.pg_auth_members m JOIN pg_catalog.pg_roles b ON (m.roleid = b.oid) WHERE m.member = r.oid) as memberof , r.rolreplication , r.rolauditadmin , r.rolsystemadmin , r.roluseft FROM pg_catalog.pg_roles r ORDER BY 1;
The authorization is successful if the dbuser information in the returned result contains the UseFT permission.
rolname | rolsuper | rolinherit | rolcreaterole | rolcreatedb | rolcanlogin | rolconnlimit | rolvalidbegin | rolvaliduntil | memberof | rolreplication | rolauditadmin | rolsystemadmin | roluseft
-----------+----------+------------+---------------+-------------+-------------+--------------+---------------+---------------+----------+----------------+---------------+----------------+----------
dbuser | f | t | f | t | t | -1 | | | {} | f | f | f | t
lily | f | t | f | f | t | -1 | | | {} | f | f | f | f
Ruby | t | t | t | t | t | -1 | | | {} | t | t | t | t
You can use the gsql client to log in to the database in either of the following ways:
You can use either of the following methods to create the connection:
\c postgres dbadmin;
Enter the password as prompted.
gsql -d postgres -h 192.168.2.30 -U dbadmin -p 8000 -W password -r
SELECT * FROM pg_foreign_server;
The returned result is as follows:
srvname | srvowner | srvfdw | srvtype | srvversion | srvacl | srvoptions --------------------------------------------------+----------+--------+---------+------------+--------+--------------------------------------------------------------------------------------------------------------------- gsmpp_server | 10 | 13673 | | | | gsmpp_errorinfo_server | 10 | 13678 | | | | hdfs_server_8f79ada0_d998_4026_9020_80d6de2692ca | 16476 | 13685 | | | | {"address=192.168.1.245:25000,192.168.1.218:25000",hdfscfgpath=/MRS/8f79ada0-d998-4026-9020-80d6de2692ca,type=hdfs} (3 rows)
In the query result, each row contains the information about a foreign server. The foreign server associated with the MRS data source connection contains the following information:
You can find the foreign server you want based on the above information and record the values of its srvname and srvoptions.
\c mydatabase dbuser;
For details about the syntax for creating foreign servers, see CREATE SERVER. For example:
CREATE SERVER hdfs_server_8f79ada0_d998_4026_9020_80d6de2692ca FOREIGN DATA WRAPPER HDFS_FDW OPTIONS ( address '192.168.1.245:25000,192.168.1.218:25000', hdfscfgpath '/MRS/8f79ada0-d998-4026-9020-80d6de2692ca', type 'hdfs' );
Mandatory parameters are described as follows:
You can customize a name.
In this example, specify the name to the value of the srvname field recorded in 2, such as hdfs_server_8f79ada0_d998_4026_9020_80d6de2692ca.
Resources in different databases are isolated. Therefore, the names of foreign servers in different databases can be the same.
This parameter can only be set to HDFS_FDW, which already exists in the database.
Specifies the IP address and port number of the primary and standby nodes of the HDFS cluster.
Specifies the configuration file path of the HDFS cluster. This parameter is available only when type is HDFS. You can set only one path.
Its value is hdfs, which indicates that HDFS_FDW connects to HDFS.
SELECT * FROM pg_foreign_server WHERE srvname='hdfs_server_8f79ada0_d998_4026_9020_80d6de2692ca';
The server is successfully created if the returned result is as follows:
srvname | srvowner | srvfdw | srvtype | srvversion | srvacl | srvoptions --------------------------------------------------+----------+--------+---------+------------+--------+--------------------------------------------------------------------------------------------------------------------- hdfs_server_8f79ada0_d998_4026_9020_80d6de2692ca | 16476 | 13685 | | | | {"address=192.168.1.245:25000,192.168.1.218:25000",hdfscfgpath=/MRS/8f79ada0-d998-4026-9020-80d6de2692ca,type=hdfs} (1 row)