YMatrix 文档
关于 YMatrix
标准集群部署
数据写入
数据迁移
数据查询
运维监控
参考指南
- MPP 架构
- 镜像分布策略
- 持续聚集
- 滑动窗口
- Grafana 监控指标解读
- Prometheus 监控指标解读
- 术语表
-
工具指南
- mxaddmirrors
- mxbackup
- mxbench
- mxdeletesystem
- mxgate
- mxinitstandby
- mxmoveseg
- mxpacklogs
- mxrecover
- mxrestore
- mxshift
- mxstart
- mxstate
- mxstop
- gpconfig
- pgvector
-
数据类型
-
存储引擎
-
执行引擎
-
系统配置参数
SQL 参考
- ABORT
- ALTER_DATABASE
- ALTER_EXTENSION
- ALTER_EXTERNAL_TABLE
- ALTER_FOREIGN_DATA_WRAPPER
- ALTER_FOREIGN_TABLE
- ALTER_FUNCTION
- ALTER_INDEX
- ALTER_RESOURCE_GROUP
- ALTER_RESOURCE_QUEUE
- ALTER_ROLE
- ALTER_RULE
- ALTER_SCHEMA
- ALTER_SEQUENCE
- ALTER_SERVER
- ALTER_TABLE
- ALTER_TABLESPACE
- ALTER_TYPE
- ALTER_USER_MAPPING
- ALTER_VIEW
- ANALYZE
- BEGIN
- CHECKPOINT
- COMMIT
- COPY
- CREATE_DATABASE
- CREATE_EXTENSION
- CREATE_EXTERNAL_TABLE
- CREATE_FOREIGN_DATA_WRAPPER
- CREATE_FOREIGN_TABLE
- CREATE_FUNCTION
- CREATE_INDEX
- CREATE_RESOURCE_GROUP
- CREATE_RESOURCE_QUEUE
- CREATE_ROLE
- CREATE_RULE
- CREATE_SCHEMA
- CREATE_SEGMENT_SET
- CREATE_SEQUENCE
- CREATE_SERVER
- CREATE_TABLE
- CREATE_TABLE_AS
- CREATE_TABLESPACE
- CREATE_TYPE
- CREATE_USER_MAPPING
- CREATE_VIEW
- DELETE
- DROP_DATABASE
- DROP_EXTENSION
- DROP_EXTERNAL_TABLE
- DROP_FOREIGN_DATA_WRAPPER
- DROP_FOREIGN_TABLE
- DROP_FUNCTION
- DROP_INDEX
- DROP_RESOURCE_GROUP
- DROP_RESOURCE_QUEUE
- DROP_ROLE
- DROP_RULE
- DROP_SCHEMA
- DROP_SEGMENT_SET
- DROP_SEQUENCE
- DROP_SERVER
- DROP_TABLE
- DROP_TABLESPACE
- DROP_TYPE
- DROP_USER_MAPPING
- DROP_VIEW
- END
- EXPLAIN
- GRANT
- INSERT
- LOAD
- LOCK
- REINDEX
- RELEASE_SAVEPOINT
- RESET
- REVOKE
- ROLLBACK_TO_SAVEPOINT
- ROLLBACK
- SAVEPOINT
- SELECT INTO
- SET ROLE
- SET TRANSACTION
- SET
- SHOW
- START TRANSACTION
- TRUNCATE
- UPDATE
- VACUUM
常见问题(FAQ)
PXF 访问 Oracle
1. Oracle 版本与表信息
SQL> SELECT * FROM V$VERSION;
BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
PL/SQL Release 11.2.0.1.0 - Production
CORE 11.2.0.1.0 Production
TNS for Linux: Version 11.2.0.1.0 - Production
NLSRTL Version 11.2.0.1.0 - Production
SQL> SELECT * FROM dept;
DEPTNO DNAME LOC
---------- --------------- ---------------
10 ACCOUNTING NEW YORK
20 RESEARCH DALLAS
30 SALES CHICAGO
40 OPERATIONS BOSTON
2. 安装
2.1 Java 安装
export JAVA_HOME=/usr/local/jdk1805
export JRE_HOME=$JAVA_HOME/jre
export CLASS_PATH=.:$JAVA_HOME/lib/dt.jar:$JAVA_HOME/lib/tools.jar:$JRE_HOME/lib
export PATH=$PATH:$JAVA_HOME/bin:$JRE_HOME/bin
2.2 PXF 安装
sudo yum install pxf-matrixdb3-5.16.1-1.el7.x86_64.rpm -y
sudo mkdir /usr/local/pxfconf
sudo chown mxadmin.mxadmin -R /usr/local/pxfconf
sudo chown mxadmin.mxadmin -R /usr/local/pxf-matrixdb4
export PXF_HOME=/usr/local/pxf-matrixdb4
export PXF_CONF=/usr/local/pxfconf
export PATH=$PXF_HOME/bin:$PATH
3. 配置
下载 Oracle 对应版本的驱动:
wget https://repo1.maven.org/maven2/com/oracle/database/jdbc/ojdbc6/11.2.0.4/ojdbc6-11.2.0.4.jar
初始化 PXF:
pxf cluster init
将驱动放入 PXF 库目录(所有节点都需要):
cp ojdbc6-11.2.0.4.jar /usr/local/pxfconf/lib/
配置 Oracle 连接串:
[mxadmin@sdw2 oracle11g]$ pwd
/usr/local/pxfconf/servers/oracle11g
[mxadmin@sdw2 oracle11g]$ cat jdbc-site.xml
<?xml version="1.0" encoding="UTF-8"?>
<configuration>
<property>
<name>jdbc.driver</name>
<value>oracle.jdbc.driver</value>
<description>Class name of the JDBC driver (e.g. org.postgresql.Driver)</description>
</property>
<property>
<name>jdbc.url</name>
<value>jdbc:oracle:thin:@sdw7:1521/orcl</value>
<description>The URL that the JDBC driver can use to connect to the database (e.g. jdbc:postgresql://localhost/postgres)</description>
</property>
<property>
<name>jdbc.user</name>
<value>scott</value>
<description>User name for connecting to the database (e.g. postgres)</description>
</property>
<property>
<name>jdbc.password</name>
<value>tiger</value>
<description>Password for connecting to the database (e.g. postgres)</description>
</property>
同步配置到其它节点:
[mxadmin@sdw2 ~]$ pxf cluster sync
Syncing PXF configuration files from master host to 1 segment host...
PXF configs synced successfully on 1 out of 1 host
4. 启动并查看集群状态
启动节点:
pxf cluster start
查看集群状态:
pxf cluster status
Checking status of PXF servers on 2 segment hosts...
PXF is running on 2 out of 2 hosts
5. 访问
创建插件:
postgres=# CREATE EXTENSION pxf_fdw ;
CREATE EXTENSION
定义 SERVER:
DROP SERVER oracle_server CASCADE;
CREATE SERVER oracle_server
FOREIGN DATA WRAPPER jdbc_pxf_fdw
OPTIONS (
jdbc_driver 'oracle.jdbc.driver.OracleDriver',
db_url 'jdbc:oracle:thin:@sdw7:1521:ORCL',
batch_size '10000',
fetch_size '2000'
);
创建用户映射:
CREATE USER MAPPING FOR mxadmin SERVER oracle_server OPTIONS ( user 'scott' , pass 'tiger' );
创建外部表:
drop FOREIGN TABLE ft_dept;
CREATE FOREIGN TABLE ft_dept(
deptno integer,
dname character varying,
loc character varying
) SERVER oracle_server
OPTIONS (resource 'DEPT');
通过外部表访问 Oracle 数据:
postgres=# SELECT * FROM ft_dept ;
deptno | dname | loc
--------+------------+----------
10 | ACCOUNTING | NEW YORK
20 | RESEARCH | DALLAS
30 | SALES | CHICAGO
40 | OPERATIONS | BOSTON
(4 rows)