├── .gitignore ├── mysql_fdw--1.0--1.1.sql ├── mysql_fdw--1.1--1.2.sql ├── .gitattributes ├── mysql_fdw.control ├── mysql_fdw--1.0.sql ├── mysql_fdw--1.1.sql ├── mysql_query.h ├── LICENSE ├── mysql_pushability.h ├── mysql_fdw--1.2.sql ├── META.json ├── Makefile ├── CONTRIBUTING.md ├── sql ├── limit_offset_pushdown.sql ├── connection_validation.sql ├── misc.sql ├── server_options.sql ├── dml.sql └── pushdown.sql ├── expected ├── connection_validation.out ├── server_options.out ├── limit_offset_pushdown_1.out ├── limit_offset_pushdown.out ├── misc.out ├── dml.out └── misc_1.out ├── mysql_init.sh ├── connection.c ├── mysql_pushability.c ├── option.c ├── mysql_fdw_pushdown.config ├── mysql_query.c └── mysql_fdw.h /.gitignore: -------------------------------------------------------------------------------- 1 | # Generated subdirectories 2 | /results/ 3 | *.o 4 | *.so 5 | -------------------------------------------------------------------------------- /mysql_fdw--1.0--1.1.sql: -------------------------------------------------------------------------------- 1 | /* mysql_fdw/mysql_fdw--1.0--1.1.sql */ 2 | 3 | CREATE OR REPLACE FUNCTION mysql_fdw_version() 4 | RETURNS pg_catalog.int4 STRICT 5 | AS 'MODULE_PATHNAME' LANGUAGE C; 6 | -------------------------------------------------------------------------------- /mysql_fdw--1.1--1.2.sql: -------------------------------------------------------------------------------- 1 | /* mysql_fdw/mysql_fdw--1.1--1.2.sql */ 2 | 3 | CREATE OR REPLACE FUNCTION mysql_fdw_display_pushdown_list(IN reload boolean DEFAULT false, 4 | OUT object_type text, 5 | OUT object_name text) 6 | RETURNS SETOF record 7 | AS 'MODULE_PATHNAME', 'mysql_display_pushdown_list' 8 | LANGUAGE C PARALLEL SAFE; 9 | -------------------------------------------------------------------------------- /.gitattributes: -------------------------------------------------------------------------------- 1 | * whitespace=space-before-tab,trailing-space 2 | *.[ch] whitespace=space-before-tab,trailing-space,indent-with-non-tab,tabwidth=4 3 | 4 | # Avoid confusing ASCII underlines with leftover merge conflict markers 5 | README conflict-marker-size=32 6 | README.* conflict-marker-size=32 7 | 8 | # Test output files that contain extra whitespace 9 | *.out -whitespace 10 | -------------------------------------------------------------------------------- /mysql_fdw.control: -------------------------------------------------------------------------------- 1 | ########################################################################## 2 | # 3 | # mysql_fdw.control 4 | # Foreign-data wrapper for remote MySQL servers 5 | # 6 | # Portions Copyright (c) 2012-2014, PostgreSQL Global Development Group 7 | # Portions Copyright (c) 2004-2025, EnterpriseDB Corporation. 8 | # 9 | # IDENTIFICATION 10 | # mysql_fdw.control 11 | # 12 | ########################################################################## 13 | 14 | comment = 'Foreign data wrapper for querying a MySQL server' 15 | default_version = '1.2' 16 | module_pathname = '$libdir/mysql_fdw' 17 | relocatable = true 18 | -------------------------------------------------------------------------------- /mysql_fdw--1.0.sql: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * mysql_fdw--1.0.sql 4 | * Foreign-data wrapper for remote MySQL servers 5 | * 6 | * Portions Copyright (c) 2012-2014, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 2004-2025, EnterpriseDB Corporation. 8 | * 9 | * IDENTIFICATION 10 | * mysql_fdw--1.0.sql 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | 15 | 16 | CREATE FUNCTION mysql_fdw_handler() 17 | RETURNS fdw_handler 18 | AS 'MODULE_PATHNAME' 19 | LANGUAGE C STRICT; 20 | 21 | CREATE FUNCTION mysql_fdw_validator(text[], oid) 22 | RETURNS void 23 | AS 'MODULE_PATHNAME' 24 | LANGUAGE C STRICT; 25 | 26 | CREATE FOREIGN DATA WRAPPER mysql_fdw 27 | HANDLER mysql_fdw_handler 28 | VALIDATOR mysql_fdw_validator; 29 | -------------------------------------------------------------------------------- /mysql_fdw--1.1.sql: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * mysql_fdw--1.1.sql 4 | * Foreign-data wrapper for remote MySQL servers 5 | * 6 | * Portions Copyright (c) 2012-2014, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 2004-2025, EnterpriseDB Corporation. 8 | * 9 | * IDENTIFICATION 10 | * mysql_fdw--1.1.sql 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | 15 | 16 | CREATE FUNCTION mysql_fdw_handler() 17 | RETURNS fdw_handler 18 | AS 'MODULE_PATHNAME' 19 | LANGUAGE C STRICT; 20 | 21 | CREATE FUNCTION mysql_fdw_validator(text[], oid) 22 | RETURNS void 23 | AS 'MODULE_PATHNAME' 24 | LANGUAGE C STRICT; 25 | 26 | CREATE FOREIGN DATA WRAPPER mysql_fdw 27 | HANDLER mysql_fdw_handler 28 | VALIDATOR mysql_fdw_validator; 29 | 30 | CREATE OR REPLACE FUNCTION mysql_fdw_version() 31 | RETURNS pg_catalog.int4 STRICT 32 | AS 'MODULE_PATHNAME' LANGUAGE C; 33 | -------------------------------------------------------------------------------- /mysql_query.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * mysql_query.h 4 | * Foreign-data wrapper for remote MySQL servers 5 | * 6 | * Portions Copyright (c) 2012-2014, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 2004-2025, EnterpriseDB Corporation. 8 | * 9 | * IDENTIFICATION 10 | * mysql_query.h 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | 15 | #ifndef MYSQL_QUERY_H 16 | #define MYSQL_QUERY_H 17 | 18 | #include "foreign/foreign.h" 19 | #include "lib/stringinfo.h" 20 | #include "nodes/pathnodes.h" 21 | #include "utils/rel.h" 22 | 23 | 24 | Datum mysql_convert_to_pg(Oid pgtyp, int pgtypmod, mysql_column *column); 25 | void mysql_bind_sql_var(Oid type, int attnum, Datum value, MYSQL_BIND *binds, 26 | bool *isnull); 27 | void mysql_bind_result(Oid pgtyp, int pgtypmod, MYSQL_FIELD *field, 28 | mysql_column *column); 29 | 30 | #endif /* MYSQL_QUERY_H */ 31 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MySQL Foreign Data Wrapper for PostgreSQL 2 | 3 | Copyright (c) 2011-2025, EnterpriseDB Corporation. 4 | 5 | Permission to use, copy, modify, and distribute this software and its 6 | documentation for any purpose, without fee, and without a written agreement is 7 | hereby granted, provided that the above copyright notice and this paragraph and 8 | the following two paragraphs appear in all copies. 9 | 10 | IN NO EVENT SHALL ENTERPRISEDB CORPORATION BE LIABLE TO ANY PARTY FOR 11 | DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST 12 | PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF 13 | ENTERPRISEDB CORPORATION HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 14 | 15 | ENTERPRISEDB CORPORATION SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, 16 | BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A 17 | PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND 18 | ENTERPRISEDB CORPORATION HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, 19 | UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 20 | -------------------------------------------------------------------------------- /mysql_pushability.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * mysql_pushability.h 4 | * prototypes for mysql_pushability.c 5 | * 6 | * Portions Copyright (c) 2022-2025, EnterpriseDB Corporation. 7 | * 8 | * IDENTIFICATION 9 | * mysql_pushability.h 10 | *------------------------------------------------------------------------- 11 | */ 12 | #ifndef MYSQL_PUSHABILITY_H 13 | #define MYSQL_PUSHABILITY_H 14 | 15 | #include "nodes/parsenodes.h" 16 | #include "nodes/pg_list.h" 17 | 18 | /* 19 | * NB: Module name must be the same as the MODULE_big configure in the Makefile 20 | * of FDW contrib module. Otherwise, the pushdown object configuration file will 21 | * not be located correctly. 22 | */ 23 | #define FDW_MODULE_NAME "mysql_fdw" 24 | 25 | /* Structure to help hold the pushdown object in the hash table */ 26 | typedef struct FDWPushdownObject 27 | { 28 | Oid objectId; 29 | ObjectType objectType; 30 | } FDWPushdownObject; 31 | 32 | extern bool mysql_check_remote_pushability(Oid objectOid); 33 | extern List *mysql_get_configured_pushdown_objects(bool reload); 34 | 35 | #endif /* MYSQL_PUSHABILITY_H */ 36 | -------------------------------------------------------------------------------- /mysql_fdw--1.2.sql: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * mysql_fdw--1.2.sql 4 | * Foreign-data wrapper for remote MySQL servers 5 | * 6 | * Portions Copyright (c) 2022-2025, EnterpriseDB Corporation. 7 | * 8 | * IDENTIFICATION 9 | * mysql_fdw--1.2.sql 10 | * 11 | *------------------------------------------------------------------------- 12 | */ 13 | 14 | 15 | CREATE FUNCTION mysql_fdw_handler() 16 | RETURNS fdw_handler 17 | AS 'MODULE_PATHNAME' 18 | LANGUAGE C STRICT; 19 | 20 | CREATE FUNCTION mysql_fdw_validator(text[], oid) 21 | RETURNS void 22 | AS 'MODULE_PATHNAME' 23 | LANGUAGE C STRICT; 24 | 25 | CREATE FOREIGN DATA WRAPPER mysql_fdw 26 | HANDLER mysql_fdw_handler 27 | VALIDATOR mysql_fdw_validator; 28 | 29 | CREATE OR REPLACE FUNCTION mysql_fdw_version() 30 | RETURNS pg_catalog.int4 STRICT 31 | AS 'MODULE_PATHNAME' LANGUAGE C; 32 | 33 | CREATE OR REPLACE FUNCTION mysql_fdw_display_pushdown_list(IN reload boolean DEFAULT false, 34 | OUT object_type text, 35 | OUT object_name text) 36 | RETURNS SETOF record 37 | AS 'MODULE_PATHNAME', 'mysql_display_pushdown_list' 38 | LANGUAGE C PARALLEL SAFE; 39 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "mysql_fdw", 3 | "abstract": "MySQL FDW for PostgreSQL 9.3+", 4 | "description": "This extension implements a Foreign Data Wrapper for MySQL. It is supported on PostgreSQL 9.3 and above.", 5 | "version": "2.1.2", 6 | "maintainer": [ 7 | "mysql_fdw@enterprisedb.com" 8 | ], 9 | "license": "postgresql", 10 | "provides": { 11 | "mysql_fdw": { 12 | "abstract": "MySQL FDW for PostgreSQL 9.3+", 13 | "file": "mysql_fdw--1.0.sql", 14 | "docfile": "README.md", 15 | "version": "2.1.2" 16 | } 17 | }, 18 | "prereqs": { 19 | "runtime": { 20 | "requires": { 21 | "PostgreSQL": "9.3.0" 22 | } 23 | } 24 | }, 25 | "resources": { 26 | "bugtracker": { 27 | "web": "https://github.com/EnterpriseDB/mysql_fdw/issues" 28 | }, 29 | "repository": { 30 | "url": "https://github.com/EnterpriseDB/mysql_fdw.git", 31 | "web": "https://github.com/EnterpriseDB/mysql_fdw", 32 | "type": "git" 33 | } 34 | }, 35 | "generated_by": "mysql_fdw@enterprisedb.com", 36 | "meta-spec": { 37 | "version": "1.0.0", 38 | "url": "http://pgxn.org/meta/spec.txt" 39 | }, 40 | "tags": [ 41 | "fdw", 42 | "mysql", 43 | "foreign data wrapper" 44 | ] 45 | } 46 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | # mysql_fdw/Makefile 2 | # 3 | # Portions Copyright (c) 2012-2014, PostgreSQL Global Development Group 4 | # Portions Copyright (c) 2004-2025, EnterpriseDB Corporation. 5 | # 6 | 7 | MODULE_big = mysql_fdw 8 | OBJS = connection.o option.o deparse.o mysql_query.o mysql_fdw.o mysql_pushability.o 9 | 10 | EXTENSION = mysql_fdw 11 | DATA = mysql_fdw--1.0.sql mysql_fdw--1.1.sql mysql_fdw--1.0--1.1.sql mysql_fdw--1.2.sql mysql_fdw--1.1--1.2.sql mysql_fdw_pushdown.config 12 | 13 | REGRESS = server_options connection_validation dml select pushdown join_pushdown aggregate_pushdown limit_offset_pushdown misc 14 | 15 | MYSQL_CONFIG = mysql_config 16 | PG_CPPFLAGS := $(shell $(MYSQL_CONFIG) --include) 17 | LIB := $(shell $(MYSQL_CONFIG) --libs) 18 | 19 | # In Debian based distros, libmariadbclient-dev provides mariadbclient (rather than mysqlclient) 20 | ifneq ($(findstring mariadbclient,$(LIB)),) 21 | MYSQL_LIB = mariadbclient 22 | else 23 | MYSQL_LIB = mysqlclient 24 | endif 25 | 26 | UNAME = uname 27 | OS := $(shell $(UNAME)) 28 | ifeq ($(OS), Darwin) 29 | DLSUFFIX = .dylib 30 | else 31 | DLSUFFIX = .so 32 | endif 33 | 34 | PG_CPPFLAGS += -D _MYSQL_LIBNAME=\"lib$(MYSQL_LIB)$(DLSUFFIX)\" 35 | 36 | ifdef USE_PGXS 37 | PG_CONFIG = pg_config 38 | PGXS := $(shell $(PG_CONFIG) --pgxs) 39 | include $(PGXS) 40 | ifndef MAJORVERSION 41 | MAJORVERSION := $(basename $(VERSION)) 42 | endif 43 | ifeq (,$(findstring $(MAJORVERSION), 13 14 15 16 17 18)) 44 | $(error PostgreSQL 13, 14, 15, 16, 17, or 18 is required to compile this extension) 45 | endif 46 | 47 | else 48 | subdir = contrib/mysql_fdw 49 | top_builddir = ../.. 50 | include $(top_builddir)/src/Makefile.global 51 | include $(top_srcdir)/contrib/contrib-global.mk 52 | endif 53 | 54 | -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | Contributing to `mysql_fdw` 2 | =========================== 3 | 4 | Following these guidelines helps to facilitate relevant discussion in 5 | pull requests and issues so the developers managing and developing this 6 | open source project can address patches and bugs as efficiently as 7 | possible. 8 | 9 | 10 | Using Issues 11 | ------------ 12 | 13 | `mysql_fdw`'s maintainers prefer that bug reports, feature requests, and 14 | pull requests are submitted as [GitHub Issues][1]. 15 | 16 | 17 | Bug Reports 18 | ----------- 19 | 20 | Before opening a bug report: 21 | 22 | 1. Search for a duplicate issue using GitHub's issue search 23 | 2. Check whether the bug remains in the latest `master` or `develop` 24 | commit 25 | 3. Create a reduced test case: remove code and data not relevant to 26 | the bug 27 | 28 | A contributor should be able to begin work on your bug without asking 29 | too many followup questions. If you include the following information, 30 | your bug will be serviced more quickly: 31 | 32 | * Short, descriptive title 33 | * Your OS 34 | * Versions of dependencies 35 | * Any custom modifications 36 | 37 | Once the background information is out of the way, you are free to 38 | present the bug itself. You should explain: 39 | 40 | * Steps you took to exercise the bug 41 | * The expected outcome 42 | * What actually occurred 43 | 44 | 45 | Feature Requests 46 | ---------------- 47 | 48 | We are open to adding features but ultimately control the scope and aims 49 | of the project. If a proposed feature is likely to incur high testing, 50 | maintenance, or performance costs it is also unlikely to be accepted. 51 | If a _strong_ case exists for a given feature, we may be persuaded on 52 | merit. Be specific. 53 | 54 | 55 | Pull Requests 56 | ------------- 57 | 58 | Well-constructed pull requests are very welcome. By _well-constructed_, 59 | we mean they do not introduce unrelated changes or break backwards 60 | compatibility. Just fork this repo and open a request against `develop`. 61 | 62 | Some examples of things likely to increase the likelihood a pull request 63 | is rejected: 64 | 65 | * Large structural changes, including: 66 | * Re-factoring for its own sake 67 | * Adding languages to the project 68 | * Unnecessary whitespace changes 69 | * Deviation from obvious conventions 70 | * Introduction of incompatible intellectual property 71 | 72 | Please do not change version numbers in your pull request: they will be 73 | updated by the project owners prior to the next release. 74 | 75 | 76 | License 77 | ------- 78 | 79 | By submitting a patch, you agree to allow the project owners to license 80 | your work under the terms of the [`LICENSE`][2]. Additionally, you grant 81 | the project owners a license under copyright covering your contribution 82 | to the extent permitted by law. Finally, you confirm that you own said 83 | copyright, have the legal authority to grant said license, and in doing 84 | so are not violating any grant of rights you have made to third parties, 85 | including your employer. 86 | 87 | [1]: https://github.com/EnterpriseDB/mysql_fdw/issues 88 | [2]: LICENSE 89 | -------------------------------------------------------------------------------- /sql/limit_offset_pushdown.sql: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | 6 | -- Before running this file User must create database mysql_fdw_regress on 7 | -- mysql with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 8 | -- and ran mysql_init.sh file to create tables. 9 | 10 | \c contrib_regression 11 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 12 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 13 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 14 | CREATE USER MAPPING FOR public SERVER mysql_svr 15 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 16 | 17 | -- Create foreign table 18 | CREATE FOREIGN TABLE f_test_tbl2 (c1 INTEGER, c2 VARCHAR(14), c3 VARCHAR(13)) 19 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl2'); 20 | 21 | INSERT INTO f_test_tbl2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 22 | INSERT INTO f_test_tbl2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 23 | INSERT INTO f_test_tbl2 VALUES(30, 'SALES', 'MUMBAI'); 24 | INSERT INTO f_test_tbl2 VALUES(40, 'HR', 'NAGPUR'); 25 | INSERT INTO f_test_tbl2 VALUES(50, 'IT', 'PUNE'); 26 | INSERT INTO f_test_tbl2 VALUES(60, 'DB SERVER', 'PUNE'); 27 | 28 | SELECT * FROM f_test_tbl2 ORDER BY 1; 29 | 30 | -- LIMIT/OFFSET pushdown. 31 | -- Limit with Offset should get pushdown. 32 | EXPLAIN (VERBOSE, COSTS FALSE) 33 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET 2; 34 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET 2; 35 | 36 | -- Only Limit should get pushdown. 37 | EXPLAIN (VERBOSE, COSTS FALSE) 38 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3; 39 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3; 40 | 41 | -- Expression in Limit clause. 42 | EXPLAIN (VERBOSE, COSTS FALSE) 43 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT round(3.2) OFFSET 2; 44 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT round(3.2) OFFSET 2; 45 | 46 | -- Only Offset without Limit should not get pushdown. 47 | EXPLAIN (VERBOSE, COSTS FALSE) 48 | SELECT * FROM f_test_tbl2 ORDER BY 1 OFFSET 2; 49 | SELECT * FROM f_test_tbl2 ORDER BY 1 OFFSET 2; 50 | 51 | -- Limit ALL 52 | EXPLAIN (VERBOSE, COSTS FALSE) 53 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT ALL; 54 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT ALL; 55 | 56 | -- Limit NULL 57 | EXPLAIN (VERBOSE, COSTS FALSE) 58 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL; 59 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL; 60 | 61 | EXPLAIN (VERBOSE, COSTS FALSE) 62 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL OFFSET 2; 63 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL OFFSET 2; 64 | 65 | -- Limit 0 and Offset 0 66 | EXPLAIN (VERBOSE, COSTS FALSE) 67 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0; 68 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0; 69 | 70 | EXPLAIN (VERBOSE, COSTS FALSE) 71 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0 OFFSET 0; 72 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0 OFFSET 0; 73 | 74 | -- Offset NULL. 75 | EXPLAIN (VERBOSE, COSTS FALSE) 76 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET NULL; 77 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET NULL; 78 | 79 | -- Limit with placeholder. 80 | EXPLAIN (VERBOSE, COSTS FALSE) 81 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (SELECT COUNT(*) FROM f_test_tbl2); 82 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (SELECT COUNT(*) FROM f_test_tbl2); 83 | 84 | -- Limit with expression, should not pushdown. 85 | EXPLAIN (VERBOSE, COSTS FALSE) 86 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (10 - (SELECT COUNT(*) FROM f_test_tbl2)); 87 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (10 - (SELECT COUNT(*) FROM f_test_tbl2)); 88 | 89 | DELETE FROM f_test_tbl2; 90 | DROP FOREIGN TABLE f_test_tbl2; 91 | DROP USER MAPPING FOR public SERVER mysql_svr; 92 | DROP SERVER mysql_svr; 93 | DROP EXTENSION mysql_fdw; 94 | -------------------------------------------------------------------------------- /sql/connection_validation.sql: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | 6 | -- Before running this file User must create database mysql_fdw_regress on 7 | -- MySQL with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 8 | -- and ran mysql_init.sh file to create tables. 9 | 10 | \c contrib_regression 11 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 12 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 13 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 14 | CREATE USER MAPPING FOR public SERVER mysql_svr 15 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 16 | 17 | -- Create foreign table and Validate 18 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 19 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 20 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 21 | 22 | -- FDW-121: After a change to a pg_foreign_server or pg_user_mapping catalog 23 | -- entry, existing connection should be invalidated and should make new 24 | -- connection using the updated connection details. 25 | 26 | -- Alter SERVER option. 27 | -- Set wrong host, subsequent operation on this server should use updated 28 | -- details and fail as the host address is not correct. The error code in error 29 | -- message is different for different server versions and platform, so check 30 | -- that through plpgsql block and give the generic error message. 31 | ALTER SERVER mysql_svr OPTIONS (SET host 'localhos'); 32 | DO 33 | $$ 34 | BEGIN 35 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 36 | EXCEPTION WHEN others THEN 37 | IF SQLERRM LIKE 'failed to connect to MySQL: Unknown %server host ''localhos'' (%)' THEN 38 | RAISE NOTICE 'failed to connect to MySQL: Unknown MySQL server host ''localhos'''; 39 | ELSE 40 | RAISE NOTICE '%', SQLERRM; 41 | END IF; 42 | END; 43 | $$ 44 | LANGUAGE plpgsql; 45 | 46 | -- Set the correct host-name, next operation should succeed. 47 | ALTER SERVER mysql_svr OPTIONS (SET host :MYSQL_HOST); 48 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 49 | 50 | -- Alter USER MAPPING option. 51 | -- Set wrong password, next operation should fail. 52 | ALTER USER MAPPING FOR PUBLIC SERVER mysql_svr 53 | OPTIONS (SET username :MYSQL_USER_NAME, SET password 'bar1'); 54 | DO 55 | $$ 56 | BEGIN 57 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 58 | EXCEPTION WHEN others THEN 59 | IF SQLERRM LIKE 'failed to connect to MySQL: Access denied for user ''%''@''%'' (using password: YES)' THEN 60 | RAISE NOTICE 'failed to connect to MySQL: Access denied for MYSQL_USER_NAME'; 61 | ELSE 62 | RAISE NOTICE '%', SQLERRM; 63 | END IF; 64 | END; 65 | $$ 66 | LANGUAGE plpgsql; 67 | 68 | -- Set correct user-name and password, next operation should succeed. 69 | ALTER USER MAPPING FOR PUBLIC SERVER mysql_svr 70 | OPTIONS (SET username :MYSQL_USER_NAME, SET password :MYSQL_PASS); 71 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 72 | 73 | 74 | -- FDW-654: Connection details should be fetched from mysql default file when 75 | -- mysql_default_file server level option is set. 76 | 77 | CREATE SERVER mysql_server FOREIGN DATA WRAPPER mysql_fdw 78 | OPTIONS (mysql_default_file '/tmp/my.cnf'); 79 | CREATE USER MAPPING FOR public SERVER mysql_server; 80 | CREATE FOREIGN TABLE f_mysql_file_test(a int, b int) SERVER mysql_server 81 | OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 82 | 83 | -- Negative scenario. Connection should not happen as default file has incorrect 84 | -- details. 85 | \! echo [client] > /tmp/my.cnf 86 | \! echo host=localhos >> /tmp/my.cnf 87 | \! echo user=$MYSQL_USER_NAME >> /tmp/my.cnf 88 | \! echo password=1234 >> /tmp/my.cnf 89 | -- Set wrong host, subsequent operation should use these connection details 90 | -- and fail as the host address is not correct. The error code in error 91 | -- message is different for different server versions and platform, so check 92 | -- that through plpgsql block and give the generic error message. 93 | DO 94 | $$ 95 | BEGIN 96 | SELECT * FROM f_mysql_file_test ORDER BY 1, 2; 97 | EXCEPTION WHEN others THEN 98 | IF SQLERRM LIKE 'failed to connect to MySQL: Unknown %server host ''localhos'' (%)' THEN 99 | RAISE NOTICE 'failed to connect to MySQL: Unknown MySQL server host ''localhos'''; 100 | ELSE 101 | RAISE NOTICE '%', SQLERRM; 102 | END IF; 103 | END; 104 | $$ 105 | LANGUAGE plpgsql; 106 | 107 | -- Prepare the default file with connection details. 108 | \! echo [client] > /tmp/my.cnf 109 | \! echo host=$MYSQL_HOST >> /tmp/my.cnf 110 | \! echo port=$MYSQL_PORT >> /tmp/my.cnf 111 | \! echo user=$MYSQL_USER_NAME >> /tmp/my.cnf 112 | \! echo password=$MYSQL_PWD >> /tmp/my.cnf 113 | \! echo secure_auth=true >> /tmp/my.cnf 114 | -- Connection should happen as default file exists with details. 115 | SELECT * FROM f_mysql_file_test ORDER BY 1, 2; 116 | 117 | 118 | -- Cleanup 119 | DROP FOREIGN TABLE f_mysql_test; 120 | DROP FOREIGN TABLE f_mysql_file_test; 121 | DROP USER MAPPING FOR public SERVER mysql_svr; 122 | DROP USER MAPPING FOR public SERVER mysql_server; 123 | DROP SERVER mysql_svr; 124 | DROP SERVER mysql_server; 125 | \! rm -f /tmp/my.cnf 126 | DROP EXTENSION mysql_fdw; 127 | -------------------------------------------------------------------------------- /expected/connection_validation.out: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | -- Before running this file User must create database mysql_fdw_regress on 6 | -- MySQL with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 7 | -- and ran mysql_init.sh file to create tables. 8 | \c contrib_regression 9 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 10 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 11 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 12 | CREATE USER MAPPING FOR public SERVER mysql_svr 13 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 14 | -- Create foreign table and Validate 15 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 16 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 17 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 18 | a | b 19 | ---+--- 20 | 1 | 1 21 | (1 row) 22 | 23 | -- FDW-121: After a change to a pg_foreign_server or pg_user_mapping catalog 24 | -- entry, existing connection should be invalidated and should make new 25 | -- connection using the updated connection details. 26 | -- Alter SERVER option. 27 | -- Set wrong host, subsequent operation on this server should use updated 28 | -- details and fail as the host address is not correct. The error code in error 29 | -- message is different for different server versions and platform, so check 30 | -- that through plpgsql block and give the generic error message. 31 | ALTER SERVER mysql_svr OPTIONS (SET host 'localhos'); 32 | DO 33 | $$ 34 | BEGIN 35 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 36 | EXCEPTION WHEN others THEN 37 | IF SQLERRM LIKE 'failed to connect to MySQL: Unknown %server host ''localhos'' (%)' THEN 38 | RAISE NOTICE 'failed to connect to MySQL: Unknown MySQL server host ''localhos'''; 39 | ELSE 40 | RAISE NOTICE '%', SQLERRM; 41 | END IF; 42 | END; 43 | $$ 44 | LANGUAGE plpgsql; 45 | NOTICE: failed to connect to MySQL: Unknown MySQL server host 'localhos' 46 | -- Set the correct host-name, next operation should succeed. 47 | ALTER SERVER mysql_svr OPTIONS (SET host :MYSQL_HOST); 48 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 49 | a | b 50 | ---+--- 51 | 1 | 1 52 | (1 row) 53 | 54 | -- Alter USER MAPPING option. 55 | -- Set wrong password, next operation should fail. 56 | ALTER USER MAPPING FOR PUBLIC SERVER mysql_svr 57 | OPTIONS (SET username :MYSQL_USER_NAME, SET password 'bar1'); 58 | DO 59 | $$ 60 | BEGIN 61 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 62 | EXCEPTION WHEN others THEN 63 | IF SQLERRM LIKE 'failed to connect to MySQL: Access denied for user ''%''@''%'' (using password: YES)' THEN 64 | RAISE NOTICE 'failed to connect to MySQL: Access denied for MYSQL_USER_NAME'; 65 | ELSE 66 | RAISE NOTICE '%', SQLERRM; 67 | END IF; 68 | END; 69 | $$ 70 | LANGUAGE plpgsql; 71 | NOTICE: failed to connect to MySQL: Access denied for MYSQL_USER_NAME 72 | -- Set correct user-name and password, next operation should succeed. 73 | ALTER USER MAPPING FOR PUBLIC SERVER mysql_svr 74 | OPTIONS (SET username :MYSQL_USER_NAME, SET password :MYSQL_PASS); 75 | SELECT * FROM f_mysql_test ORDER BY 1, 2; 76 | a | b 77 | ---+--- 78 | 1 | 1 79 | (1 row) 80 | 81 | -- FDW-654: Connection details should be fetched from mysql default file when 82 | -- mysql_default_file server level option is set. 83 | CREATE SERVER mysql_server FOREIGN DATA WRAPPER mysql_fdw 84 | OPTIONS (mysql_default_file '/tmp/my.cnf'); 85 | CREATE USER MAPPING FOR public SERVER mysql_server; 86 | CREATE FOREIGN TABLE f_mysql_file_test(a int, b int) SERVER mysql_server 87 | OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 88 | -- Negative scenario. Connection should not happen as default file has incorrect 89 | -- details. 90 | \! echo [client] > /tmp/my.cnf 91 | \! echo host=localhos >> /tmp/my.cnf 92 | \! echo user=$MYSQL_USER_NAME >> /tmp/my.cnf 93 | \! echo password=1234 >> /tmp/my.cnf 94 | -- Set wrong host, subsequent operation should use these connection details 95 | -- and fail as the host address is not correct. The error code in error 96 | -- message is different for different server versions and platform, so check 97 | -- that through plpgsql block and give the generic error message. 98 | DO 99 | $$ 100 | BEGIN 101 | SELECT * FROM f_mysql_file_test ORDER BY 1, 2; 102 | EXCEPTION WHEN others THEN 103 | IF SQLERRM LIKE 'failed to connect to MySQL: Unknown %server host ''localhos'' (%)' THEN 104 | RAISE NOTICE 'failed to connect to MySQL: Unknown MySQL server host ''localhos'''; 105 | ELSE 106 | RAISE NOTICE '%', SQLERRM; 107 | END IF; 108 | END; 109 | $$ 110 | LANGUAGE plpgsql; 111 | NOTICE: failed to connect to MySQL: Unknown MySQL server host 'localhos' 112 | -- Prepare the default file with connection details. 113 | \! echo [client] > /tmp/my.cnf 114 | \! echo host=$MYSQL_HOST >> /tmp/my.cnf 115 | \! echo port=$MYSQL_PORT >> /tmp/my.cnf 116 | \! echo user=$MYSQL_USER_NAME >> /tmp/my.cnf 117 | \! echo password=$MYSQL_PWD >> /tmp/my.cnf 118 | \! echo secure_auth=true >> /tmp/my.cnf 119 | -- Connection should happen as default file exists with details. 120 | SELECT * FROM f_mysql_file_test ORDER BY 1, 2; 121 | a | b 122 | ---+--- 123 | 1 | 1 124 | (1 row) 125 | 126 | -- Cleanup 127 | DROP FOREIGN TABLE f_mysql_test; 128 | DROP FOREIGN TABLE f_mysql_file_test; 129 | DROP USER MAPPING FOR public SERVER mysql_svr; 130 | DROP USER MAPPING FOR public SERVER mysql_server; 131 | DROP SERVER mysql_svr; 132 | DROP SERVER mysql_server; 133 | \! rm -f /tmp/my.cnf 134 | DROP EXTENSION mysql_fdw; 135 | -------------------------------------------------------------------------------- /sql/misc.sql: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | 6 | -- Before running this file User must create database mysql_fdw_regress on 7 | -- MySQL with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 8 | -- and ran mysql_init.sh file to create tables. 9 | 10 | \c contrib_regression 11 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 12 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 13 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 14 | CREATE USER MAPPING FOR public SERVER mysql_svr 15 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 16 | CREATE SERVER mysql_svr1 FOREIGN DATA WRAPPER mysql_fdw 17 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 18 | CREATE USER MAPPING FOR public SERVER mysql_svr1 19 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 20 | 21 | -- Create foreign tables and insert data. 22 | CREATE FOREIGN TABLE fdw519_ft1(stu_id int, stu_name varchar(255), stu_dept int) 23 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student'); 24 | CREATE FOREIGN TABLE fdw519_ft2(c1 INTEGER, c2 VARCHAR(14), c3 VARCHAR(13)) 25 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl2'); 26 | CREATE FOREIGN TABLE fdw519_ft3 (c1 INTEGER, c2 VARCHAR(10), c3 CHAR(9), c4 BIGINT, c5 pg_catalog.Date, c6 DECIMAL, c7 INTEGER, c8 SMALLINT) 27 | SERVER mysql_svr1 OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl1'); 28 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 29 | INSERT INTO fdw519_ft2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 30 | INSERT INTO fdw519_ft2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 31 | INSERT INTO fdw519_ft3 VALUES (100, 'EMP1', 'ADMIN', 1300, '1980-12-17', 800.23, NULL, 20); 32 | INSERT INTO fdw519_ft3 VALUES (200, 'EMP2', 'SALESMAN', 600, '1981-02-20', 1600.00, 300, 30); 33 | 34 | -- Check truncatable option with invalid values. 35 | -- Since truncatable option is available since v14, this gives an error on v13 36 | -- and previous versions. 37 | ALTER SERVER mysql_svr OPTIONS (ADD truncatable 'abc'); 38 | ALTER FOREIGN TABLE fdw519_ft1 OPTIONS (ADD truncatable 'abc'); 39 | 40 | -- Default behavior, should truncate. 41 | TRUNCATE fdw519_ft1; 42 | SELECT * FROM fdw519_ft1 ORDER BY 1; 43 | 44 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 45 | 46 | -- Set truncatable to false 47 | -- Since truncatable option is available since v14, this gives an error on v13 48 | -- and previous versions. 49 | ALTER SERVER mysql_svr OPTIONS (ADD truncatable 'false'); 50 | 51 | -- Truncate the table. 52 | TRUNCATE fdw519_ft1; 53 | SELECT * FROM fdw519_ft1 ORDER BY 1; 54 | 55 | -- Set truncatable to true 56 | -- Since truncatable option is available since v14, this gives an error on v13 57 | -- and previous versions. 58 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'true'); 59 | TRUNCATE fdw519_ft1; 60 | SELECT * FROM fdw519_ft1 ORDER BY 1; 61 | 62 | -- truncatable to true on Server but false on table level. 63 | -- Since truncatable option is available since v14, this gives an error on v13 64 | -- and previous versions. 65 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'false'); 66 | ALTER TABLE fdw519_ft2 OPTIONS (ADD truncatable 'true'); 67 | SELECT * FROM fdw519_ft2 ORDER BY 1; 68 | TRUNCATE fdw519_ft2; 69 | SELECT * FROM fdw519_ft2 ORDER BY 1; 70 | 71 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 72 | INSERT INTO fdw519_ft2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 73 | INSERT INTO fdw519_ft2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 74 | 75 | -- truncatable to true on Server but false on one table and true for other 76 | -- table. 77 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'true'); 78 | ALTER TABLE fdw519_ft1 OPTIONS (ADD truncatable 'false'); 79 | ALTER TABLE fdw519_ft2 OPTIONS (SET truncatable 'true'); 80 | TRUNCATE fdw519_ft1, fdw519_ft2; 81 | SELECT * FROM fdw519_ft1 ORDER BY 1; 82 | SELECT * FROM fdw519_ft2 ORDER BY 1; 83 | 84 | -- truncatable to false on Server but false on one table and true for other 85 | -- table. 86 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'false'); 87 | ALTER TABLE fdw519_ft1 OPTIONS (SET truncatable 'false'); 88 | ALTER TABLE fdw519_ft2 OPTIONS (SET truncatable 'true'); 89 | TRUNCATE fdw519_ft1, fdw519_ft2; 90 | SELECT * FROM fdw519_ft1 ORDER BY 1; 91 | SELECT * FROM fdw519_ft2 ORDER BY 1; 92 | 93 | -- Truncate from different servers. 94 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'true'); 95 | ALTER SERVER mysql_svr1 OPTIONS (ADD truncatable 'true'); 96 | ALTER TABLE fdw519_ft1 OPTIONS (SET truncatable 'true'); 97 | TRUNCATE fdw519_ft1, fdw519_ft2, fdw519_ft3; 98 | SELECT * FROM fdw519_ft1 ORDER BY 1; 99 | SELECT * FROM fdw519_ft2 ORDER BY 1; 100 | SELECT * FROM fdw519_ft3 ORDER BY 1; 101 | 102 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 103 | SELECT * FROM fdw519_ft1 ORDER BY 1; 104 | -- Truncate with CASCADE is not supported. 105 | TRUNCATE fdw519_ft1 CASCADE; 106 | SELECT * FROM fdw519_ft1 ORDER BY 1; 107 | -- Default is RESTRICT, so it is allowed. 108 | TRUNCATE fdw519_ft1 RESTRICT; 109 | SELECT * FROM fdw519_ft1 ORDER BY 1; 110 | 111 | -- Should throw an error if primary key is referenced by foreign key. 112 | CREATE FOREIGN TABLE fdw519_ft4(stu_id varchar(10), stu_name varchar(255), stu_dept int) 113 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student1'); 114 | CREATE FOREIGN TABLE fdw519_ft5(dept_id int, stu_id varchar(10)) 115 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'dept'); 116 | TRUNCATE fdw519_ft4; 117 | 118 | -- FDW-520: Support generated columns in IMPORT FOREIGN SCHEMA command. 119 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520) 120 | FROM SERVER mysql_svr INTO public OPTIONS (import_generated 'true'); 121 | \d fdw520 122 | 123 | -- Generated column refers to another generated column, should throw an error: 124 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520_1) 125 | FROM SERVER mysql_svr INTO public OPTIONS (import_generated 'true'); 126 | 127 | -- import_generated as false. 128 | DROP FOREIGN TABLE fdw520; 129 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520) 130 | FROM SERVER mysql_svr INTO public OPTIONS (import_generated 'false'); 131 | \d fdw520 132 | 133 | -- Without import_generated option, default is true. 134 | DROP FOREIGN TABLE fdw520; 135 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520) 136 | FROM SERVER mysql_svr INTO public; 137 | \d fdw520 138 | 139 | -- FDW-521: Insert and update operations on table having generated columns. 140 | INSERT INTO fdw520(c1, "c `"""" 2") VALUES(1, 2); 141 | INSERT INTO fdw520(c1, "c `"""" 2", c3, c4) VALUES(2, 4, DEFAULT, DEFAULT); 142 | -- Should fail. 143 | INSERT INTO fdw520 VALUES(1, 2, 3, 4); 144 | SELECT * FROM fdw520 ORDER BY 1; 145 | UPDATE fdw520 SET "c `"""" 2" = 20 WHERE c1 = 2; 146 | SELECT * FROM fdw520 ORDER BY 1; 147 | -- Should fail. 148 | UPDATE fdw520 SET c4 = 20 WHERE c1 = 2; 149 | UPDATE fdw520 SET c3 = 20 WHERE c1 = 2; 150 | 151 | -- Cleanup 152 | DELETE FROM fdw519_ft1; 153 | DELETE FROM fdw519_ft2; 154 | DELETE FROM fdw519_ft3; 155 | DELETE FROM fdw520; 156 | DROP FOREIGN TABLE fdw519_ft1; 157 | DROP FOREIGN TABLE fdw519_ft2; 158 | DROP FOREIGN TABLE fdw519_ft3; 159 | DROP FOREIGN TABLE fdw519_ft4; 160 | DROP FOREIGN TABLE fdw519_ft5; 161 | DROP FOREIGN TABLE fdw520; 162 | DROP USER MAPPING FOR public SERVER mysql_svr; 163 | DROP SERVER mysql_svr; 164 | DROP USER MAPPING FOR public SERVER mysql_svr1; 165 | DROP SERVER mysql_svr1; 166 | DROP EXTENSION mysql_fdw; 167 | -------------------------------------------------------------------------------- /mysql_init.sh: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | export MYSQL_PWD="${MYSQL_PWD:=edb}" 3 | export MYSQL_HOST="${MYSQL_HOST:=localhost}" 4 | export MYSQL_PORT="${MYSQL_PORT:=3306}" 5 | export MYSQL_USER_NAME="${MYSQL_USER_NAME:=edb}" 6 | 7 | # Below commands must be run first time to create mysql_fdw_regress and mysql_fdw_regress1 databases 8 | # used in regression tests with edb user and edb password. 9 | # --connect to mysql with root user 10 | # mysql -u root -p 11 | 12 | # --run below 13 | # CREATE DATABASE mysql_fdw_regress; 14 | # CREATE DATABASE mysql_fdw_regress1; 15 | # SET GLOBAL validate_password.policy = LOW; 16 | # SET GLOBAL validate_password.length = 1; 17 | # SET GLOBAL validate_password.mixed_case_count = 0; 18 | # SET GLOBAL validate_password.number_count = 0; 19 | # SET GLOBAL validate_password.special_char_count = 0; 20 | # CREATE USER 'edb'@'localhost' IDENTIFIED BY 'edb'; 21 | # GRANT ALL PRIVILEGES ON mysql_fdw_regress.* TO 'edb'@'localhost'; 22 | # GRANT ALL PRIVILEGES ON mysql_fdw_regress1.* TO 'edb'@'localhost'; 23 | 24 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS mysql_test;" 25 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS empdata;" 26 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS numbers;" 27 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test_tbl2;" 28 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test_tbl1;" 29 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "DROP TABLE IF EXISTS student;" 30 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "DROP TABLE IF EXISTS numbers;" 31 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS enum_t1;" 32 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "DROP TABLE IF EXISTS dept;" 33 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "DROP TABLE IF EXISTS student1;" 34 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS enum_t2;" 35 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test1;" 36 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test2;" 37 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test3;" 38 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test4;" 39 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test5;" 40 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test_set;" 41 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test6;" 42 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS test7;" 43 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS distinct_test;" 44 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS fdw520;" 45 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS fdw520_1;" 46 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS \`fdw-601\`;" 47 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS timestamp_test;" 48 | 49 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE mysql_test(a int primary key, b int not null);" 50 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "INSERT INTO mysql_test(a,b) VALUES (1,1);" 51 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE empdata (emp_id int, emp_dat blob, PRIMARY KEY (emp_id));" 52 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE numbers (a int PRIMARY KEY, b varchar(255));" 53 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test_tbl1 (c1 INT primary key, c2 VARCHAR(10), c3 CHAR(9), c4 MEDIUMINT, c5 DATE, c6 DECIMAL(10,5), c7 INT, c8 SMALLINT);" 54 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test_tbl2 (c1 INT primary key, c2 TEXT, c3 TEXT);" 55 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "CREATE TABLE student (stu_id int PRIMARY KEY, stu_name text, stu_dept int);" 56 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "CREATE TABLE numbers (a int, b varchar(255));" 57 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE enum_t1 (id int PRIMARY KEY, size ENUM('small', 'medium', 'large'));" 58 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "CREATE TABLE student1 (stu_id varchar(10) PRIMARY KEY, stu_name text, stu_dept int);" 59 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE enum_t2 (id int PRIMARY KEY, size ENUM('S', 'M', 'L'));" 60 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "INSERT INTO enum_t2 VALUES (10, 'S'),(20, 'M'),(30, 'M');" 61 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test1 (c1 int PRIMARY KEY, c2 int, c3 varchar(255), c4 ENUM ('foo', 'bar', 'buz'))" 62 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test2 (c1 int PRIMARY KEY, c2 int, c3 varchar(255), c4 ENUM ('foo', 'bar', 'buz'))" 63 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test3 (c1 int PRIMARY KEY, c2 int, c3 varchar(255))" 64 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test4 (c1 int PRIMARY KEY, c2 int, c3 varchar(255))" 65 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test5 (c1 int primary key, c2 binary, c3 binary(3), c4 binary(1), c5 binary(10), c6 varbinary(3), c7 varbinary(1), c8 varbinary(10), c9 binary(0), c10 varbinary(0));" 66 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "INSERT INTO test5 VALUES (1, 'c', 'c3c', 't', 'c5c5c5', '04', '1', '01-10-2021', NULL, '');" 67 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test_set (c1 int primary key, c2 SET('a', 'b', 'c', 'd'), c3 int);" 68 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test6 (c1 numeric(6,4))" 69 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "INSERT INTO test6 VALUES (25.252525)" 70 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test7 (c1 int primary key auto_increment, c2 longtext NOT NULL);" 71 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "INSERT INTO test7 (c2) SELECT repeat('abcdefgh ', 7500);" 72 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE distinct_test (id int primary key, c1 int, c2 int, c3 text, c4 text);" 73 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "CREATE TABLE dept (dept_id int PRIMARY KEY, stu_id varchar(10), FOREIGN KEY (stu_id) REFERENCES student1(stu_id));" 74 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e 'CREATE TABLE fdw520 (c1 int primary key, `c ``"" 2` int, c3 int generated always as (`c ``"" 2` * 2) stored, c4 int generated always as (`c ``"" 2` * 4) virtual not null);' 75 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE fdw520_1 (c1 int primary key, c2 int, c3 int generated always as (c2 * 2) stored, c4 int generated always as (c3 * 4) stored not null);" 76 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE \`fdw-601\` (a int primary key, b int);" 77 | mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE timestamp_test(a int primary key, b timestamp);" 78 | -------------------------------------------------------------------------------- /sql/server_options.sql: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | 6 | -- Before running this file User must create database mysql_fdw_regress on 7 | -- MySQL with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 8 | -- and ran mysql_init.sh file to create tables. 9 | 10 | \c contrib_regression 11 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 12 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 13 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 14 | CREATE USER MAPPING FOR public SERVER mysql_svr 15 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 16 | 17 | -- Validate extension, server and mapping details 18 | CREATE OR REPLACE FUNCTION show_details(host TEXT, port TEXT, uid TEXT, pwd TEXT) RETURNS int AS $$ 19 | DECLARE 20 | ext TEXT; 21 | srv TEXT; 22 | sopts TEXT; 23 | uopts TEXT; 24 | BEGIN 25 | SELECT e.fdwname, srvname, array_to_string(s.srvoptions, ','), array_to_string(u.umoptions, ',') 26 | INTO ext, srv, sopts, uopts 27 | FROM pg_foreign_data_wrapper e LEFT JOIN pg_foreign_server s ON e.oid = s.srvfdw LEFT JOIN pg_user_mapping u ON s.oid = u.umserver 28 | WHERE e.fdwname = 'mysql_fdw' 29 | ORDER BY 1, 2, 3, 4; 30 | 31 | raise notice 'Extension : %', ext; 32 | raise notice 'Server : %', srv; 33 | 34 | IF strpos(sopts, host) <> 0 AND strpos(sopts, port) <> 0 THEN 35 | raise notice 'Server_Options : matched'; 36 | END IF; 37 | 38 | IF strpos(uopts, uid) <> 0 AND strpos(uopts, pwd) <> 0 THEN 39 | raise notice 'User_Mapping_Options : matched'; 40 | END IF; 41 | 42 | return 1; 43 | END; 44 | $$ language plpgsql; 45 | 46 | SELECT show_details(:MYSQL_HOST, :MYSQL_PORT, :MYSQL_USER_NAME, :MYSQL_PASS); 47 | 48 | -- Create foreign table and perform basic SQL operations 49 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 50 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 51 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 52 | INSERT INTO f_mysql_test (a, b) VALUES (2, 2); 53 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 54 | UPDATE f_mysql_test SET b = 3 WHERE a = 2; 55 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 56 | DELETE FROM f_mysql_test WHERE a = 2; 57 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 58 | 59 | DROP FOREIGN TABLE f_mysql_test; 60 | DROP USER MAPPING FOR public SERVER mysql_svr; 61 | DROP SERVER mysql_svr; 62 | 63 | -- Server with init_command. 64 | CREATE SERVER mysql_svr1 FOREIGN DATA WRAPPER mysql_fdw 65 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT, init_command 'create table init_command_check(a int)'); 66 | CREATE USER MAPPING FOR public SERVER mysql_svr1 67 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 68 | CREATE FOREIGN TABLE f_mysql_test (a int, b int) 69 | SERVER mysql_svr1 OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 70 | -- This will create init_command_check table in mysql_fdw_regress database. 71 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 72 | 73 | -- init_command_check table created mysql_fdw_regress database can be verified 74 | -- by creating corresponding foreign table here. 75 | CREATE FOREIGN TABLE f_init_command_check(a int) 76 | SERVER mysql_svr1 OPTIONS (dbname 'mysql_fdw_regress', table_name 'init_command_check'); 77 | SELECT a FROM f_init_command_check ORDER BY 1; 78 | -- Changing init_command to drop init_command_check table from 79 | -- mysql_fdw_regress database 80 | ALTER SERVER mysql_svr1 OPTIONS (SET init_command 'drop table init_command_check'); 81 | SELECT a, b FROM f_mysql_test; 82 | 83 | DROP FOREIGN TABLE f_init_command_check; 84 | DROP FOREIGN TABLE f_mysql_test; 85 | DROP USER MAPPING FOR public SERVER mysql_svr1; 86 | DROP SERVER mysql_svr1; 87 | 88 | -- Server with use_remote_estimate. 89 | CREATE SERVER mysql_svr1 FOREIGN DATA WRAPPER mysql_fdw 90 | OPTIONS(host :MYSQL_HOST, port :MYSQL_PORT, use_remote_estimate 'TRUE'); 91 | CREATE USER MAPPING FOR public SERVER mysql_svr1 92 | OPTIONS(username :MYSQL_USER_NAME, password :MYSQL_PASS); 93 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 94 | SERVER mysql_svr1 OPTIONS(dbname 'mysql_fdw_regress', table_name 'mysql_test'); 95 | 96 | -- Below explain will return actual rows from MySQL, but keeping costs off 97 | -- here for consistent regression result. 98 | EXPLAIN (VERBOSE, COSTS OFF) SELECT a FROM f_mysql_test WHERE a < 2 ORDER BY 1; 99 | 100 | DROP FOREIGN TABLE f_mysql_test; 101 | DROP USER MAPPING FOR public SERVER mysql_svr1; 102 | DROP SERVER mysql_svr1; 103 | 104 | -- Create server with secure_auth. 105 | CREATE SERVER mysql_svr1 FOREIGN DATA WRAPPER mysql_fdw 106 | OPTIONS(host :MYSQL_HOST, port :MYSQL_PORT, secure_auth 'FALSE'); 107 | CREATE USER MAPPING FOR public SERVER mysql_svr1 108 | OPTIONS(username :MYSQL_USER_NAME, password :MYSQL_PASS); 109 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 110 | SERVER mysql_svr1 OPTIONS(dbname 'mysql_fdw_regress', table_name 'mysql_test'); 111 | 112 | -- Below should fail with Warning of secure_auth is false. 113 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 114 | DROP FOREIGN TABLE f_mysql_test; 115 | DROP USER MAPPING FOR public SERVER mysql_svr1; 116 | DROP SERVER mysql_svr1; 117 | 118 | -- FDW-335: Support for fetch_size option at server level and table level. 119 | CREATE SERVER fetch101 FOREIGN DATA WRAPPER mysql_fdw 120 | OPTIONS( fetch_size '101' ); 121 | 122 | SELECT count(*) 123 | FROM pg_foreign_server 124 | WHERE srvname = 'fetch101' 125 | AND srvoptions @> array['fetch_size=101']; 126 | 127 | ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' ); 128 | 129 | SELECT count(*) 130 | FROM pg_foreign_server 131 | WHERE srvname = 'fetch101' 132 | AND srvoptions @> array['fetch_size=101']; 133 | 134 | SELECT count(*) 135 | FROM pg_foreign_server 136 | WHERE srvname = 'fetch101' 137 | AND srvoptions @> array['fetch_size=202']; 138 | 139 | CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 140 | OPTIONS ( fetch_size '30000' ); 141 | 142 | SELECT COUNT(*) 143 | FROM pg_foreign_table 144 | WHERE ftrelid = 'table30000'::regclass 145 | AND ftoptions @> array['fetch_size=30000']; 146 | 147 | ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000'); 148 | 149 | SELECT COUNT(*) 150 | FROM pg_foreign_table 151 | WHERE ftrelid = 'table30000'::regclass 152 | AND ftoptions @> array['fetch_size=30000']; 153 | 154 | SELECT COUNT(*) 155 | FROM pg_foreign_table 156 | WHERE ftrelid = 'table30000'::regclass 157 | AND ftoptions @> array['fetch_size=60000']; 158 | 159 | -- Make sure that changing the table level fetch-size value did not change the 160 | -- server level value. 161 | SELECT count(*) 162 | FROM pg_foreign_server 163 | WHERE srvname = 'fetch101' 164 | AND srvoptions @> array['fetch_size=202']; 165 | 166 | -- Negative test cases for fetch_size option, should error out. 167 | ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '-60000'); 168 | ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '123abc'); 169 | ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '999999999999999999999'); 170 | 171 | -- Cleanup fetch_size test objects. 172 | DROP FOREIGN TABLE table30000; 173 | DROP SERVER fetch101; 174 | 175 | -- FDW-350: Support for reconnect option at server level. 176 | CREATE SERVER reconnect1 FOREIGN DATA WRAPPER mysql_fdw 177 | OPTIONS( reconnect 'true' ); 178 | 179 | SELECT count(*) 180 | FROM pg_foreign_server 181 | WHERE srvname = 'reconnect1' 182 | AND srvoptions @> array['reconnect=true']; 183 | 184 | ALTER SERVER reconnect1 OPTIONS( SET reconnect 'false' ); 185 | 186 | SELECT count(*) 187 | FROM pg_foreign_server 188 | WHERE srvname = 'reconnect1' 189 | AND srvoptions @> array['reconnect=false']; 190 | 191 | -- Negative test case for reconnect option, should error out. 192 | ALTER SERVER reconnect1 OPTIONS ( SET reconnect 'abc1' ); 193 | 194 | -- Cleanup reconnect option test objects. 195 | DROP SERVER reconnect1; 196 | 197 | -- FDW-404: Support for character_set option at server level. 198 | CREATE SERVER charset101 FOREIGN DATA WRAPPER mysql_fdw 199 | OPTIONS( character_set 'utf8' ); 200 | 201 | SELECT count(*) 202 | FROM pg_foreign_server 203 | WHERE srvname = 'charset101' 204 | AND srvoptions @> array['character_set=utf8']; 205 | 206 | ALTER SERVER charset101 OPTIONS( SET character_set 'latin' ); 207 | 208 | SELECT count(*) 209 | FROM pg_foreign_server 210 | WHERE srvname = 'charset101' 211 | AND srvoptions @> array['character_set=latin']; 212 | 213 | -- Cleanup character_set test objects. 214 | DROP SERVER charset101; 215 | 216 | -- Cleanup 217 | DROP EXTENSION mysql_fdw; 218 | -------------------------------------------------------------------------------- /connection.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * connection.c 4 | * Connection management functions for mysql_fdw 5 | * 6 | * Portions Copyright (c) 2012-2014, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 2004-2025, EnterpriseDB Corporation. 8 | * 9 | * IDENTIFICATION 10 | * connection.c 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | 15 | #include "postgres.h" 16 | 17 | #include "common/hashfn.h" 18 | #include "mysql_fdw.h" 19 | #include "utils/hsearch.h" 20 | #include "utils/inval.h" 21 | #include "utils/memutils.h" 22 | #include "utils/syscache.h" 23 | 24 | /* Length of host */ 25 | #define HOST_LEN 256 26 | 27 | /* 28 | * Connection cache hash table entry 29 | * 30 | * The lookup key in this hash table is the foreign server OID plus the user 31 | * mapping OID. (We use just one connection per user per foreign server, 32 | * so that we can ensure all scans use the same snapshot during a query.) 33 | */ 34 | typedef struct ConnCacheKey 35 | { 36 | Oid serverid; /* OID of foreign server */ 37 | Oid userid; /* OID of local user whose mapping we use */ 38 | } ConnCacheKey; 39 | 40 | typedef struct ConnCacheEntry 41 | { 42 | ConnCacheKey key; /* hash key (must be first) */ 43 | MYSQL *conn; /* connection to foreign server, or NULL */ 44 | bool invalidated; /* true if reconnect is pending */ 45 | uint32 server_hashvalue; /* hash value of foreign server OID */ 46 | uint32 mapping_hashvalue; /* hash value of user mapping OID */ 47 | } ConnCacheEntry; 48 | 49 | /* 50 | * Connection cache (initialized on first use) 51 | */ 52 | static HTAB *ConnectionHash = NULL; 53 | 54 | static void mysql_inval_callback(Datum arg, int cacheid, uint32 hashvalue); 55 | 56 | /* 57 | * mysql_get_connection: 58 | * Get a connection which can be used to execute queries on the remote 59 | * MySQL server with the user's authorization. A new connection is 60 | * established if we don't already have a suitable one. 61 | */ 62 | MYSQL * 63 | mysql_get_connection(ForeignServer *server, UserMapping *user, mysql_opt *opt) 64 | { 65 | bool found; 66 | ConnCacheEntry *entry; 67 | ConnCacheKey key; 68 | 69 | /* First time through, initialize connection cache hashtable */ 70 | if (ConnectionHash == NULL) 71 | { 72 | HASHCTL ctl; 73 | 74 | MemSet(&ctl, 0, sizeof(ctl)); 75 | ctl.keysize = sizeof(ConnCacheKey); 76 | ctl.entrysize = sizeof(ConnCacheEntry); 77 | ctl.hash = tag_hash; 78 | 79 | /* Allocate ConnectionHash in the cache context */ 80 | ctl.hcxt = CacheMemoryContext; 81 | ConnectionHash = hash_create("mysql_fdw connections", 8, 82 | &ctl, 83 | HASH_ELEM | HASH_FUNCTION | HASH_CONTEXT); 84 | 85 | /* 86 | * Register some callback functions that manage connection cleanup. 87 | * This should be done just once in each backend. 88 | */ 89 | CacheRegisterSyscacheCallback(FOREIGNSERVEROID, 90 | mysql_inval_callback, (Datum) 0); 91 | CacheRegisterSyscacheCallback(USERMAPPINGOID, 92 | mysql_inval_callback, (Datum) 0); 93 | } 94 | 95 | /* Create hash key for the entry. Assume no pad bytes in key struct */ 96 | key.serverid = server->serverid; 97 | key.userid = user->userid; 98 | 99 | /* 100 | * Find or create cached entry for requested connection. 101 | */ 102 | entry = hash_search(ConnectionHash, &key, HASH_ENTER, &found); 103 | if (!found) 104 | { 105 | /* Initialize new hashtable entry (key is already filled in) */ 106 | entry->conn = NULL; 107 | } 108 | 109 | /* If an existing entry has invalid connection then release it */ 110 | if (entry->conn != NULL && entry->invalidated) 111 | { 112 | elog(DEBUG3, "disconnecting mysql_fdw connection %p for option changes to take effect", 113 | entry->conn); 114 | mysql_close(entry->conn); 115 | entry->conn = NULL; 116 | } 117 | 118 | if (entry->conn == NULL) 119 | { 120 | entry->conn = mysql_fdw_connect(opt); 121 | elog(DEBUG3, "new mysql_fdw connection %p for server \"%s\"", 122 | entry->conn, server->servername); 123 | 124 | /* 125 | * Once the connection is established, then set the connection 126 | * invalidation flag to false, also set the server and user mapping 127 | * hash values. 128 | */ 129 | entry->invalidated = false; 130 | entry->server_hashvalue = 131 | GetSysCacheHashValue1(FOREIGNSERVEROID, 132 | ObjectIdGetDatum(server->serverid)); 133 | 134 | entry->mapping_hashvalue = 135 | GetSysCacheHashValue1(USERMAPPINGOID, 136 | ObjectIdGetDatum(user->umid)); 137 | } 138 | return entry->conn; 139 | } 140 | 141 | /* 142 | * mysql_cleanup_connection: 143 | * Delete all the cache entries on backend exists. 144 | */ 145 | void 146 | mysql_cleanup_connection(void) 147 | { 148 | HASH_SEQ_STATUS scan; 149 | ConnCacheEntry *entry; 150 | 151 | if (ConnectionHash == NULL) 152 | return; 153 | 154 | hash_seq_init(&scan, ConnectionHash); 155 | while ((entry = (ConnCacheEntry *) hash_seq_search(&scan))) 156 | { 157 | if (entry->conn == NULL) 158 | continue; 159 | 160 | elog(DEBUG3, "disconnecting mysql_fdw connection %p", entry->conn); 161 | mysql_close(entry->conn); 162 | entry->conn = NULL; 163 | } 164 | } 165 | 166 | /* 167 | * Release connection created by calling mysql_get_connection. 168 | */ 169 | void 170 | mysql_release_connection(MYSQL *conn) 171 | { 172 | HASH_SEQ_STATUS scan; 173 | ConnCacheEntry *entry; 174 | 175 | if (ConnectionHash == NULL) 176 | return; 177 | 178 | hash_seq_init(&scan, ConnectionHash); 179 | while ((entry = (ConnCacheEntry *) hash_seq_search(&scan))) 180 | { 181 | if (entry->conn == NULL) 182 | continue; 183 | 184 | if (entry->conn == conn) 185 | { 186 | elog(DEBUG3, "disconnecting mysql_fdw connection %p", entry->conn); 187 | mysql_close(entry->conn); 188 | entry->conn = NULL; 189 | hash_seq_term(&scan); 190 | break; 191 | } 192 | } 193 | } 194 | 195 | MYSQL * 196 | mysql_fdw_connect(mysql_opt *opt) 197 | { 198 | MYSQL *conn; 199 | char *svr_database = opt->svr_database; 200 | bool svr_sa = opt->svr_sa; 201 | char *svr_init_command = opt->svr_init_command; 202 | char *ssl_cipher = opt->ssl_cipher; 203 | #if MYSQL_VERSION_ID < 80000 204 | my_bool secure_auth = svr_sa; 205 | #endif 206 | 207 | /* Connect to the server */ 208 | conn = mysql_init(NULL); 209 | if (!conn) 210 | ereport(ERROR, 211 | (errcode(ERRCODE_FDW_OUT_OF_MEMORY), 212 | errmsg("failed to initialise the MySQL connection object"))); 213 | 214 | mysql_options(conn, MYSQL_SET_CHARSET_NAME, opt->character_set); 215 | #if MYSQL_VERSION_ID < 80000 216 | mysql_options(conn, MYSQL_SECURE_AUTH, &secure_auth); 217 | #endif 218 | 219 | if (!svr_sa) 220 | elog(WARNING, "MySQL secure authentication is off"); 221 | 222 | if (svr_init_command != NULL) 223 | mysql_options(conn, MYSQL_INIT_COMMAND, svr_init_command); 224 | 225 | /* 226 | * Enable or disable automatic reconnection to the MySQL server if the 227 | * existing connection is found to have been lost. 228 | */ 229 | mysql_options(conn, MYSQL_OPT_RECONNECT, &opt->reconnect); 230 | 231 | /* 232 | * If the mysql_default_file option is provided, then read the connection 233 | * details from the given file. 234 | */ 235 | if (opt->mysql_default_file) 236 | { 237 | mysql_options(conn, MYSQL_READ_DEFAULT_FILE, 238 | (void *)opt->mysql_default_file); 239 | if (!mysql_real_connect(conn, NULL, NULL, NULL, NULL, 0, NULL, 0)) 240 | ereport(ERROR, 241 | (errcode(ERRCODE_FDW_UNABLE_TO_ESTABLISH_CONNECTION), 242 | errmsg("failed to connect to MySQL: %s", 243 | mysql_error(conn)))); 244 | } 245 | else 246 | { 247 | mysql_ssl_set(conn, opt->ssl_key, opt->ssl_cert, opt->ssl_ca, 248 | opt->ssl_capath, ssl_cipher); 249 | 250 | if (!mysql_real_connect(conn, opt->svr_address, opt->svr_username, 251 | opt->svr_password, svr_database, opt->svr_port, 252 | NULL, 0)) 253 | ereport(ERROR, 254 | (errcode(ERRCODE_FDW_UNABLE_TO_ESTABLISH_CONNECTION), 255 | errmsg("failed to connect to MySQL: %s", 256 | mysql_error(conn)))); 257 | } 258 | 259 | /* Useful for verifying that the connection's secured */ 260 | elog(DEBUG1, 261 | "Successfully connected to MySQL database %s at server %s with cipher %s (server version: %s, protocol version: %d) ", 262 | (svr_database != NULL) ? svr_database : "", 263 | mysql_get_host_info(conn), 264 | (ssl_cipher != NULL) ? ssl_cipher : "", 265 | mysql_get_server_info(conn), 266 | mysql_get_proto_info(conn)); 267 | 268 | return conn; 269 | } 270 | 271 | /* 272 | * Connection invalidation callback function for mysql. 273 | * 274 | * After a change to a pg_foreign_server or pg_user_mapping catalog entry, 275 | * mark connections depending on that entry as needing to be remade. This 276 | * implementation is similar as pgfdw_inval_callback. 277 | */ 278 | static void 279 | mysql_inval_callback(Datum arg, int cacheid, uint32 hashvalue) 280 | { 281 | HASH_SEQ_STATUS scan; 282 | ConnCacheEntry *entry; 283 | 284 | Assert(cacheid == FOREIGNSERVEROID || cacheid == USERMAPPINGOID); 285 | 286 | /* ConnectionHash must exist already, if we're registered */ 287 | hash_seq_init(&scan, ConnectionHash); 288 | while ((entry = (ConnCacheEntry *) hash_seq_search(&scan))) 289 | { 290 | /* Ignore invalid entries */ 291 | if (entry->conn == NULL) 292 | continue; 293 | 294 | /* hashvalue == 0 means a cache reset, must clear all state */ 295 | if (hashvalue == 0 || 296 | (cacheid == FOREIGNSERVEROID && 297 | entry->server_hashvalue == hashvalue) || 298 | (cacheid == USERMAPPINGOID && 299 | entry->mapping_hashvalue == hashvalue)) 300 | entry->invalidated = true; 301 | } 302 | } 303 | -------------------------------------------------------------------------------- /mysql_pushability.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * mysql_pushability.c 4 | * routines for FDW pushability 5 | * 6 | * Portions Copyright (c) 2022-2025, EnterpriseDB Corporation. 7 | * 8 | * IDENTIFICATION 9 | * mysql_pushability.c 10 | * 11 | *------------------------------------------------------------------------- 12 | */ 13 | #include "postgres.h" 14 | 15 | #include "common/string.h" 16 | #include "fmgr.h" 17 | #include "lib/stringinfo.h" 18 | #include "miscadmin.h" 19 | #include "mysql_pushability.h" 20 | #include "storage/fd.h" 21 | #include "utils/fmgrprotos.h" 22 | #include "utils/hsearch.h" 23 | #include "utils/memutils.h" 24 | 25 | static char *get_config_filename(void); 26 | static void populate_pushability_hash(void); 27 | static void config_invalid_error_callback(void *arg); 28 | static bool get_line_buf(FILE *stream, StringInfo buf); 29 | 30 | /* Hash table for caching the configured pushdown objects */ 31 | static HTAB *pushabilityHash = NULL; 32 | 33 | /* 34 | * Memory context to hold the hash table, need to free incase of any error 35 | * while parsing the configuration file. 36 | */ 37 | static MemoryContext htab_ctx; 38 | 39 | 40 | /* 41 | * get_config_filename 42 | * Returns the path for the pushdown object configuration file for the 43 | * foreign-data wrapper. 44 | */ 45 | static char * 46 | get_config_filename(void) 47 | { 48 | char sharepath[MAXPGPATH]; 49 | char *result; 50 | 51 | get_share_path(my_exec_path, sharepath); 52 | result = (char *) palloc(MAXPGPATH); 53 | snprintf(result, MAXPGPATH, "%s/extension/%s_pushdown.config", sharepath, 54 | FDW_MODULE_NAME); 55 | 56 | return result; 57 | } 58 | 59 | /* 60 | * mysql_check_remote_pushability 61 | * Lookups into hash table by forming the hash key from provided object 62 | * oid. 63 | */ 64 | bool 65 | mysql_check_remote_pushability(Oid object_oid) 66 | { 67 | bool found = false; 68 | 69 | /* Populate pushability hash if not already. */ 70 | if (unlikely(!pushabilityHash)) 71 | populate_pushability_hash(); 72 | 73 | hash_search(pushabilityHash, &object_oid, HASH_FIND, &found); 74 | 75 | return found; 76 | } 77 | 78 | /* 79 | * populate_pushability_hash 80 | * Creates the hash table and populates the hash entries by reading the 81 | * pushdown object configuration file. 82 | */ 83 | static void 84 | populate_pushability_hash(void) 85 | { 86 | FILE *file = NULL; 87 | char *config_filename; 88 | HASHCTL ctl; 89 | ErrorContextCallback errcallback; 90 | unsigned int line_no = 0; 91 | StringInfoData linebuf; 92 | HTAB *hash; 93 | 94 | Assert(pushabilityHash == NULL); 95 | 96 | /* 97 | * Create a memory context to hold hash table. This makes it easy to 98 | * clean up in the case of error, we don't make the context long-lived 99 | * until we parse the complete config file without an error. 100 | */ 101 | htab_ctx = AllocSetContextCreate(CurrentMemoryContext, 102 | "mysql pushability_hash", 103 | ALLOCSET_DEFAULT_SIZES); 104 | ctl.keysize = sizeof(Oid); 105 | ctl.entrysize = sizeof(FDWPushdownObject); 106 | ctl.hcxt = htab_ctx; 107 | 108 | /* Create the hash table */ 109 | hash = hash_create("mysql_fdw push elements hash", 256, 110 | &ctl, HASH_ELEM | HASH_BLOBS | HASH_CONTEXT); 111 | 112 | /* Get the config file name */ 113 | config_filename = get_config_filename(); 114 | 115 | file = AllocateFile(config_filename, PG_BINARY_R); 116 | 117 | if (file == NULL) 118 | ereport(ERROR, 119 | (errcode_for_file_access(), 120 | errmsg("could not open \"%s\": %m", config_filename))); 121 | 122 | /* Set up callback to provide the error context */ 123 | errcallback.callback = config_invalid_error_callback; 124 | errcallback.arg = (void *) config_filename; 125 | errcallback.previous = error_context_stack; 126 | error_context_stack = &errcallback; 127 | 128 | initStringInfo(&linebuf); 129 | 130 | /* 131 | * Read the pushdown object configuration file and push object information 132 | * to the in-memory hash table for a faster lookup. 133 | */ 134 | while (get_line_buf(file, &linebuf)) 135 | { 136 | FDWPushdownObject *entry; 137 | Oid objectId; 138 | ObjectType objectType; 139 | bool found; 140 | char *str; 141 | 142 | line_no++; 143 | 144 | /* If record starts with #, then consider as comment. */ 145 | if (linebuf.data[0] == '#') 146 | continue; 147 | 148 | /* Ignore if all blank */ 149 | if (strspn(linebuf.data, " \t\r\n") == linebuf.len) 150 | continue; 151 | 152 | /* Strip trailing newline, including \r in case we're on Windows */ 153 | while (linebuf.len > 0 && (linebuf.data[linebuf.len - 1] == '\n' || 154 | linebuf.data[linebuf.len - 1] == '\r')) 155 | linebuf.data[--linebuf.len] = '\0'; 156 | 157 | /* Strip leading whitespaces. */ 158 | str = linebuf.data; 159 | while (isspace(*str)) 160 | str++; 161 | 162 | if (pg_strncasecmp(str, "ROUTINE", 7) == 0) 163 | { 164 | /* Move over ROUTINE */ 165 | str = str + 7; 166 | 167 | /* Move over any whitespace */ 168 | while (isspace(*str)) 169 | str++; 170 | 171 | objectType = OBJECT_FUNCTION; 172 | objectId = 173 | DatumGetObjectId(DirectFunctionCall1(regprocedurein, 174 | CStringGetDatum(str))); 175 | } 176 | else if (pg_strncasecmp(str, "OPERATOR", 8) == 0) 177 | { 178 | /* Move over OPERATOR */ 179 | str = str + 8; 180 | 181 | /* Move over any whitespace */ 182 | while (isspace(*str)) 183 | str++; 184 | 185 | objectType = OBJECT_OPERATOR; 186 | objectId = 187 | DatumGetObjectId(DirectFunctionCall1(regoperatorin, 188 | CStringGetDatum(str))); 189 | } 190 | else 191 | ereport(ERROR, 192 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 193 | errmsg("invalid object type in configuration file at line number: %d", 194 | line_no), 195 | errhint("Valid values are: \"ROUTINE\", \"OPERATOR\"."))); 196 | 197 | /* Insert the new element to the hash table */ 198 | entry = hash_search(hash, &objectId, HASH_ENTER, &found); 199 | 200 | /* Two different objects cannot have the same system object id */ 201 | if (found && entry->objectType != objectType) 202 | elog(ERROR, "different pushdown objects have the same oid \"%d\"", 203 | objectId); 204 | 205 | entry->objectType = objectType; 206 | } 207 | 208 | if (ferror(file)) 209 | ereport(ERROR, 210 | (errcode_for_file_access(), 211 | errmsg("could not read file \"%s\": %m", config_filename))); 212 | 213 | error_context_stack = errcallback.previous; 214 | 215 | pfree(linebuf.data); 216 | 217 | FreeFile(file); 218 | 219 | /* 220 | * We have fully parsed the config file. Reparent hash table context so 221 | * that it has the right lifespan. 222 | */ 223 | MemoryContextSetParent(htab_ctx, CacheMemoryContext); 224 | pushabilityHash = hash; 225 | } 226 | 227 | /* 228 | * config_invalid_error_callback 229 | * Error callback to define the context. 230 | */ 231 | static void 232 | config_invalid_error_callback(void *arg) 233 | { 234 | char *filename = (char *) arg; 235 | 236 | /* Destroy the hash in case of error */ 237 | hash_destroy(pushabilityHash); 238 | pushabilityHash = NULL; 239 | 240 | errcontext("while processing \"%s\" file", filename); 241 | } 242 | 243 | /* 244 | * get_line_buf 245 | * Returns true if a line was successfully collected (including 246 | * the case of a non-newline-terminated line at EOF). 247 | * 248 | * Returns false if there was an I/O error or no data was available 249 | * before EOF. In the false-result case, buf is reset to empty. 250 | * (Borrowed the code from pg_get_line_buf().) 251 | */ 252 | bool 253 | get_line_buf(FILE *stream, StringInfo buf) 254 | { 255 | int orig_len; 256 | 257 | /* We just need to drop any data from the previous call */ 258 | resetStringInfo(buf); 259 | 260 | orig_len = buf->len; 261 | 262 | /* Read some data, appending it to whatever we already have */ 263 | while (fgets(buf->data + buf->len, buf->maxlen - buf->len, stream) != NULL) 264 | { 265 | buf->len += strlen(buf->data + buf->len); 266 | 267 | /* Done if we have collected a newline */ 268 | if (buf->len > orig_len && buf->data[buf->len - 1] == '\n') 269 | return true; 270 | 271 | /* Make some more room in the buffer, and loop to read more data */ 272 | enlargeStringInfo(buf, 128); 273 | } 274 | 275 | /* Check for I/O errors and EOF */ 276 | if (ferror(stream) || buf->len == orig_len) 277 | { 278 | /* Discard any data we collected before detecting error */ 279 | buf->len = orig_len; 280 | buf->data[orig_len] = '\0'; 281 | return false; 282 | } 283 | 284 | /* No newline at EOF, but we did collect some data */ 285 | return true; 286 | } 287 | 288 | /* 289 | * mysql_get_configured_pushdown_objects 290 | * Returns the hash table objects by sequentially scanning the hash table. 291 | */ 292 | List * 293 | mysql_get_configured_pushdown_objects(bool reload) 294 | { 295 | List *result = NIL; 296 | HASH_SEQ_STATUS scan; 297 | FDWPushdownObject *entry; 298 | FDWPushdownObject *object; 299 | Size size = sizeof(FDWPushdownObject); 300 | 301 | /* 302 | * To avoid the memory leak, destroy the existing hash in case of 303 | * reloading. 304 | */ 305 | if (reload) 306 | { 307 | hash_destroy(pushabilityHash); 308 | pushabilityHash = NULL; 309 | MemoryContextDelete(htab_ctx); 310 | } 311 | 312 | /* Reload configuration if that not loaded at all */ 313 | if (!pushabilityHash) 314 | populate_pushability_hash(); 315 | 316 | hash_seq_init(&scan, pushabilityHash); 317 | while ((entry = (FDWPushdownObject *) hash_seq_search(&scan)) != NULL) 318 | { 319 | object = (FDWPushdownObject *) palloc(size); 320 | memcpy(object, entry, size); 321 | result = lappend(result, object); 322 | } 323 | 324 | return result; 325 | } 326 | -------------------------------------------------------------------------------- /sql/dml.sql: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | 6 | -- Before running this file User must create database mysql_fdw_regress on 7 | -- MySQL with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 8 | -- and ran mysql_init.sh file to create tables. 9 | 10 | \c contrib_regression 11 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 12 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 13 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 14 | CREATE USER MAPPING FOR public SERVER mysql_svr 15 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 16 | 17 | -- Create foreign tables 18 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 19 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 20 | CREATE FOREIGN TABLE fdw126_ft1(stu_id int, stu_name varchar(255), stu_dept int) 21 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student'); 22 | CREATE FOREIGN TABLE fdw126_ft2(stu_id int, stu_name varchar(255)) 23 | SERVER mysql_svr OPTIONS (table_name 'student'); 24 | CREATE FOREIGN TABLE fdw126_ft3(a int, b varchar(255)) 25 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'numbers'); 26 | CREATE FOREIGN TABLE fdw126_ft4(a int, b varchar(255)) 27 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'nosuchtable'); 28 | CREATE FOREIGN TABLE fdw126_ft5(a int, b varchar(255)) 29 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress2', table_name 'numbers'); 30 | CREATE FOREIGN TABLE fdw126_ft6(stu_id int, stu_name varchar(255)) 31 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'mysql_fdw_regress1.student'); 32 | CREATE FOREIGN TABLE f_empdata(emp_id int, emp_dat bytea) 33 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'empdata'); 34 | CREATE FOREIGN TABLE fdw193_ft1(stu_id varchar(10), stu_name varchar(255), stu_dept int) 35 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student1'); 36 | 37 | 38 | -- Operation on blob data. 39 | INSERT INTO f_empdata VALUES (1, decode ('01234567', 'hex')); 40 | INSERT INTO f_empdata VALUES (2, 'abc'); 41 | SELECT count(*) FROM f_empdata ORDER BY 1; 42 | SELECT emp_id, emp_dat FROM f_empdata ORDER BY 1; 43 | UPDATE f_empdata SET emp_dat = decode ('0123', 'hex') WHERE emp_id = 1; 44 | SELECT emp_id, emp_dat FROM f_empdata ORDER BY 1; 45 | 46 | -- FDW-126: Insert/update/delete statement failing in mysql_fdw by picking 47 | -- wrong database name. 48 | 49 | -- Verify the INSERT/UPDATE/DELETE operations on another foreign table which 50 | -- resides in the another database in MySQL. The previous commands performs 51 | -- the operation on foreign table created for tables in mysql_fdw_regress 52 | -- MySQL database. Below operations will be performed for foreign table 53 | -- created for table in mysql_fdw_regress1 MySQL database. 54 | INSERT INTO fdw126_ft1 VALUES(1, 'One', 101); 55 | UPDATE fdw126_ft1 SET stu_name = 'one' WHERE stu_id = 1; 56 | DELETE FROM fdw126_ft1 WHERE stu_id = 1; 57 | 58 | -- Select on f_mysql_test foreign table which is created for mysql_test table 59 | -- from mysql_fdw_regress MySQL database. This call is just to cross verify if 60 | -- everything is working correctly. 61 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 62 | 63 | -- Insert into fdw126_ft2 table which does not have dbname specified while 64 | -- creating the foreign table, so it will consider the schema name of foreign 65 | -- table as database name and try to connect/lookup into that database. Will 66 | -- throw an error. The error message is different on old mysql and mariadb 67 | -- servers so give the generic message. 68 | DO 69 | $$ 70 | BEGIN 71 | INSERT INTO fdw126_ft2 VALUES(2, 'Two'); 72 | EXCEPTION WHEN others THEN 73 | IF SQLERRM LIKE '%SELECT command denied to user ''%''@''%'' for table ''student''' THEN 74 | RAISE NOTICE E'failed to execute the MySQL query: \nUnknown database ''public'''; 75 | ELSE 76 | RAISE NOTICE '%', SQLERRM; 77 | END IF; 78 | END; 79 | $$ 80 | LANGUAGE plpgsql; 81 | 82 | -- Check with the same table name from different database. fdw126_ft3 is 83 | -- pointing to the mysql_fdw_regress1.numbers and not mysql_fdw_regress.numbers 84 | -- table. INSERT/UPDATE/DELETE should be failing. SELECT will return no rows. 85 | INSERT INTO fdw126_ft3 VALUES(1, 'One'); 86 | SELECT a, b FROM fdw126_ft3 ORDER BY 1, 2 LIMIT 1; 87 | UPDATE fdw126_ft3 SET b = 'one' WHERE a = 1; 88 | DELETE FROM fdw126_ft3 WHERE a = 1; 89 | 90 | -- Check when table_name is given in database.table form in foreign table 91 | -- should error out as table does not exists. 92 | INSERT INTO fdw126_ft6 VALUES(1, 'One'); 93 | 94 | -- Perform the ANALYZE on the foreign table which is not present on the remote 95 | -- side. Should not crash. 96 | -- The database is present but not the target table. 97 | ANALYZE fdw126_ft4; 98 | -- The database itself is not present. 99 | ANALYZE fdw126_ft5; 100 | -- Some other variant of analyze and vacuum. 101 | -- when table exists, should give skip-warning 102 | VACUUM f_empdata; 103 | VACUUM FULL f_empdata; 104 | VACUUM FREEZE f_empdata; 105 | ANALYZE f_empdata; 106 | ANALYZE f_empdata(emp_id); 107 | VACUUM ANALYZE f_empdata; 108 | 109 | -- Verify the before update trigger which modifies the column value which is not 110 | -- part of update statement. 111 | CREATE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 112 | BEGIN 113 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 114 | RETURN NEW; 115 | END 116 | $$ language plpgsql; 117 | 118 | CREATE TRIGGER before_row_update_trig 119 | BEFORE UPDATE ON fdw126_ft1 120 | FOR EACH ROW EXECUTE PROCEDURE before_row_update_func(); 121 | 122 | INSERT INTO fdw126_ft1 VALUES(1, 'One', 101); 123 | UPDATE fdw126_ft1 SET stu_dept = 201 WHERE stu_id = 1; 124 | SELECT * FROM fdw126_ft1 ORDER BY stu_id; 125 | 126 | -- Throw an error when target list has row identifier column. 127 | UPDATE fdw126_ft1 SET stu_dept = 201, stu_id = 10 WHERE stu_id = 1; 128 | 129 | -- Throw an error when before row update trigger modify the row identifier 130 | -- column (int column) value. 131 | CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 132 | BEGIN 133 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 134 | NEW.stu_id = 20; 135 | RETURN NEW; 136 | END 137 | $$ language plpgsql; 138 | 139 | UPDATE fdw126_ft1 SET stu_dept = 301 WHERE stu_id = 1; 140 | 141 | -- Verify the before update trigger which modifies the column value which is 142 | -- not part of update statement. 143 | CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 144 | BEGIN 145 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 146 | RETURN NEW; 147 | END 148 | $$ language plpgsql; 149 | 150 | CREATE TRIGGER before_row_update_trig1 151 | BEFORE UPDATE ON fdw193_ft1 152 | FOR EACH ROW EXECUTE PROCEDURE before_row_update_func(); 153 | 154 | INSERT INTO fdw193_ft1 VALUES('aa', 'One', 101); 155 | UPDATE fdw193_ft1 SET stu_dept = 201 WHERE stu_id = 'aa'; 156 | SELECT * FROM fdw193_ft1 ORDER BY stu_id; 157 | 158 | -- Throw an error when before row update trigger modify the row identifier 159 | -- column (varchar column) value. 160 | CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 161 | BEGIN 162 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 163 | NEW.stu_id = 'bb'; 164 | RETURN NEW; 165 | END 166 | $$ language plpgsql; 167 | 168 | UPDATE fdw193_ft1 SET stu_dept = 301 WHERE stu_id = 'aa'; 169 | 170 | -- Verify the NULL assignment scenario. 171 | CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 172 | BEGIN 173 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 174 | NEW.stu_id = NULL; 175 | RETURN NEW; 176 | END 177 | $$ language plpgsql; 178 | 179 | UPDATE fdw193_ft1 SET stu_dept = 401 WHERE stu_id = 'aa'; 180 | 181 | -- FDW-224 Fix COPY FROM and foreign partition routing result in server crash 182 | -- Should fail as foreign table direct copy not supported 183 | COPY f_mysql_test TO stdout; 184 | COPY f_mysql_test (a) TO stdout; 185 | 186 | -- Should pass 187 | COPY (SELECT * FROM f_mysql_test) TO stdout; 188 | COPY (SELECT a FROM f_mysql_test) TO '/tmp/copy_test.txt' delimiter ','; 189 | 190 | -- Should give error message as copy from with foreign table not supported 191 | DO 192 | $$ 193 | BEGIN 194 | COPY f_mysql_test(a) FROM '/tmp/copy_test.txt' delimiter ','; 195 | EXCEPTION WHEN others THEN 196 | IF SQLERRM = 'COPY and foreign partition routing not supported in mysql_fdw' OR 197 | SQLERRM = 'cannot copy to foreign table "f_mysql_test"' THEN 198 | RAISE NOTICE 'ERROR: COPY and foreign partition routing not supported in mysql_fdw'; 199 | ELSE 200 | RAISE NOTICE '%', SQLERRM; 201 | END IF; 202 | END; 203 | $$ 204 | LANGUAGE plpgsql; 205 | 206 | -- FDW-518: Should honor ON CONFLICT DO NOTHING clause. 207 | 208 | SELECT * FROM f_mysql_test ORDER BY 1; 209 | -- Should not throw an error while inserting duplicate value as we are using 210 | -- ON CONFLICT DO NOTHING clause. 211 | INSERT INTO f_mysql_test VALUES(1,1) ON CONFLICT DO NOTHING; 212 | SELECT * FROM f_mysql_test ORDER BY 1; 213 | 214 | -- Should throw an error 215 | INSERT INTO f_mysql_test VALUES(1,1) ON CONFLICT (a, b) DO NOTHING; 216 | INSERT INTO f_mysql_test VALUES(1,1) ON CONFLICT DO UPDATE SET b = 10; 217 | INSERT INTO f_mysql_test VALUES(1,1) ON CONFLICT (a) DO UPDATE SET b = 10; 218 | 219 | -- FDW-601: database and table name should be quoted correctly in case of 220 | -- INSERT/UPDATE/DELETE. 221 | CREATE FOREIGN TABLE fdw601(a int, b int) 222 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'fdw-601'); 223 | INSERT INTO fdw601 VALUES(1,1), (2,2); 224 | UPDATE fdw601 SET b = 3 WHERE b = 2; 225 | DELETE FROM fdw601 WHERE b = 1; 226 | SELECT * FROM fdw601 ORDER BY 1; 227 | DELETE FROM fdw601; 228 | 229 | -- Cleanup 230 | DELETE FROM fdw126_ft1; 231 | DELETE FROM f_empdata; 232 | DELETE FROM fdw193_ft1; 233 | DROP FOREIGN TABLE f_mysql_test; 234 | DROP FOREIGN TABLE fdw126_ft1; 235 | DROP FOREIGN TABLE fdw126_ft2; 236 | DROP FOREIGN TABLE fdw126_ft3; 237 | DROP FOREIGN TABLE fdw126_ft4; 238 | DROP FOREIGN TABLE fdw126_ft5; 239 | DROP FOREIGN TABLE fdw126_ft6; 240 | DROP FOREIGN TABLE f_empdata; 241 | DROP FOREIGN TABLE fdw193_ft1; 242 | DROP FOREIGN TABLE fdw601; 243 | DROP FUNCTION before_row_update_func(); 244 | DROP USER MAPPING FOR public SERVER mysql_svr; 245 | DROP SERVER mysql_svr; 246 | DROP EXTENSION mysql_fdw; 247 | -------------------------------------------------------------------------------- /option.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * option.c 4 | * FDW option handling for mysql_fdw 5 | * 6 | * Portions Copyright (c) 2012-2014, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 2004-2025, EnterpriseDB Corporation. 8 | * 9 | * IDENTIFICATION 10 | * option.c 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | #include "postgres.h" 15 | 16 | #include "access/reloptions.h" 17 | #include "catalog/pg_foreign_server.h" 18 | #include "catalog/pg_foreign_table.h" 19 | #include "catalog/pg_user_mapping.h" 20 | #include "catalog/pg_type.h" 21 | #include "commands/defrem.h" 22 | #include "mb/pg_wchar.h" 23 | #include "miscadmin.h" 24 | #include "mysql_fdw.h" 25 | #include "utils/lsyscache.h" 26 | 27 | /* 28 | * Describes the valid options for objects that use this wrapper. 29 | */ 30 | struct MySQLFdwOption 31 | { 32 | const char *optname; 33 | Oid optcontext; /* Oid of catalog in which option may appear */ 34 | }; 35 | 36 | /* 37 | * Valid options for mysql_fdw. 38 | */ 39 | static struct MySQLFdwOption valid_options[] = 40 | { 41 | /* Connection options */ 42 | {"host", ForeignServerRelationId}, 43 | {"port", ForeignServerRelationId}, 44 | {"init_command", ForeignServerRelationId}, 45 | {"username", UserMappingRelationId}, 46 | {"password", UserMappingRelationId}, 47 | {"dbname", ForeignTableRelationId}, 48 | {"table_name", ForeignTableRelationId}, 49 | {"secure_auth", ForeignServerRelationId}, 50 | {"max_blob_size", ForeignTableRelationId}, 51 | {"use_remote_estimate", ForeignServerRelationId}, 52 | /* fetch_size is available on both server and table */ 53 | {"fetch_size", ForeignServerRelationId}, 54 | {"fetch_size", ForeignTableRelationId}, 55 | {"reconnect", ForeignServerRelationId}, 56 | {"character_set", ForeignServerRelationId}, 57 | {"mysql_default_file", ForeignServerRelationId}, 58 | #if PG_VERSION_NUM >= 140000 59 | /* truncatable is available on both server and table */ 60 | {"truncatable", ForeignServerRelationId}, 61 | {"truncatable", ForeignTableRelationId}, 62 | #endif 63 | {"sql_mode", ForeignServerRelationId}, 64 | {"ssl_key", ForeignServerRelationId}, 65 | {"ssl_cert", ForeignServerRelationId}, 66 | {"ssl_ca", ForeignServerRelationId}, 67 | {"ssl_capath", ForeignServerRelationId}, 68 | {"ssl_cipher", ForeignServerRelationId}, 69 | 70 | /* Sentinel */ 71 | {NULL, InvalidOid} 72 | }; 73 | 74 | extern Datum mysql_fdw_validator(PG_FUNCTION_ARGS); 75 | 76 | PG_FUNCTION_INFO_V1(mysql_fdw_validator); 77 | 78 | /* 79 | * Validate the generic options given to a FOREIGN DATA WRAPPER, SERVER, 80 | * USER MAPPING or FOREIGN TABLE that uses file_fdw. 81 | * 82 | * Raise an ERROR if the option or its value is considered invalid. 83 | */ 84 | Datum 85 | mysql_fdw_validator(PG_FUNCTION_ARGS) 86 | { 87 | List *options_list = untransformRelOptions(PG_GETARG_DATUM(0)); 88 | Oid catalog = PG_GETARG_OID(1); 89 | ListCell *cell; 90 | 91 | /* 92 | * Check that only options supported by mysql_fdw, and allowed for the 93 | * current object type, are given. 94 | */ 95 | foreach(cell, options_list) 96 | { 97 | DefElem *def = (DefElem *) lfirst(cell); 98 | 99 | if (!mysql_is_valid_option(def->defname, catalog)) 100 | { 101 | struct MySQLFdwOption *opt; 102 | StringInfoData buf; 103 | 104 | /* 105 | * Unknown option specified, complain about it. Provide a hint 106 | * with list of valid options for the object. 107 | */ 108 | initStringInfo(&buf); 109 | for (opt = valid_options; opt->optname; opt++) 110 | { 111 | if (catalog == opt->optcontext) 112 | appendStringInfo(&buf, "%s%s", (buf.len > 0) ? ", " : "", 113 | opt->optname); 114 | } 115 | 116 | ereport(ERROR, 117 | (errcode(ERRCODE_FDW_INVALID_OPTION_NAME), 118 | errmsg("invalid option \"%s\"", def->defname), 119 | errhint("Valid options in this context are: %s", 120 | buf.len ? buf.data : ""))); 121 | } 122 | 123 | /* Validate fetch_size option value */ 124 | if (strcmp(def->defname, "fetch_size") == 0) 125 | { 126 | unsigned long fetch_size; 127 | char *endptr; 128 | char *inputVal = defGetString(def); 129 | 130 | while (inputVal && isspace((unsigned char) *inputVal)) 131 | inputVal++; 132 | 133 | if (inputVal && *inputVal == '-') 134 | ereport(ERROR, 135 | (errcode(ERRCODE_SYNTAX_ERROR), 136 | errmsg("\"%s\" requires an integer value between 1 to %lu", 137 | def->defname, ULONG_MAX))); 138 | 139 | errno = 0; 140 | fetch_size = strtoul(inputVal, &endptr, 10); 141 | 142 | if (*endptr != '\0' || 143 | (errno == ERANGE && fetch_size == ULONG_MAX) || 144 | fetch_size == 0) 145 | ereport(ERROR, 146 | (errcode(ERRCODE_SYNTAX_ERROR), 147 | errmsg("\"%s\" requires an integer value between 1 to %lu", 148 | def->defname, ULONG_MAX))); 149 | } 150 | else if (strcmp(def->defname, "reconnect") == 0) 151 | { 152 | /* accept only boolean values */ 153 | (void) defGetBoolean(def); 154 | } 155 | #if PG_VERSION_NUM >= 140000 156 | else if (strcmp(def->defname, "truncatable") == 0) 157 | { 158 | /* accept only boolean values */ 159 | (void) defGetBoolean(def); 160 | } 161 | #endif 162 | } 163 | 164 | PG_RETURN_VOID(); 165 | } 166 | 167 | /* 168 | * Check if the provided option is one of the valid options. 169 | * context is the Oid of the catalog holding the object the option is for. 170 | */ 171 | bool 172 | mysql_is_valid_option(const char *option, Oid context) 173 | { 174 | struct MySQLFdwOption *opt; 175 | 176 | for (opt = valid_options; opt->optname; opt++) 177 | { 178 | if (context == opt->optcontext && strcmp(opt->optname, option) == 0) 179 | return true; 180 | } 181 | 182 | return false; 183 | } 184 | 185 | /* 186 | * Fetch the options for a mysql_fdw foreign table. 187 | */ 188 | mysql_opt * 189 | mysql_get_options(Oid foreignoid, bool is_foreigntable) 190 | { 191 | ForeignTable *f_table; 192 | ForeignServer *f_server; 193 | UserMapping *f_mapping; 194 | List *options; 195 | ListCell *lc; 196 | mysql_opt *opt; 197 | 198 | opt = (mysql_opt *) palloc0(sizeof(mysql_opt)); 199 | 200 | /* 201 | * Extract options from FDW objects. 202 | */ 203 | if (is_foreigntable) 204 | { 205 | f_table = GetForeignTable(foreignoid); 206 | f_server = GetForeignServer(f_table->serverid); 207 | } 208 | else 209 | { 210 | f_table = NULL; 211 | f_server = GetForeignServer(foreignoid); 212 | } 213 | 214 | f_mapping = GetUserMapping(GetUserId(), f_server->serverid); 215 | 216 | options = NIL; 217 | 218 | options = mysql_list_concat(options, f_server->options); 219 | options = mysql_list_concat(options, f_mapping->options); 220 | 221 | if (f_table) 222 | options = mysql_list_concat(options, f_table->options); 223 | 224 | /* Default secure authentication is true */ 225 | opt->svr_sa = true; 226 | 227 | opt->use_remote_estimate = false; 228 | opt->reconnect = false; 229 | 230 | /* Loop through the options */ 231 | foreach(lc, options) 232 | { 233 | DefElem *def = (DefElem *) lfirst(lc); 234 | 235 | if (strcmp(def->defname, "host") == 0) 236 | opt->svr_address = defGetString(def); 237 | 238 | if (strcmp(def->defname, "port") == 0) 239 | opt->svr_port = atoi(defGetString(def)); 240 | 241 | if (strcmp(def->defname, "username") == 0) 242 | opt->svr_username = defGetString(def); 243 | 244 | if (strcmp(def->defname, "password") == 0) 245 | opt->svr_password = defGetString(def); 246 | 247 | if (strcmp(def->defname, "dbname") == 0) 248 | opt->svr_database = defGetString(def); 249 | 250 | if (strcmp(def->defname, "table_name") == 0) 251 | opt->svr_table = defGetString(def); 252 | 253 | if (strcmp(def->defname, "secure_auth") == 0) 254 | opt->svr_sa = defGetBoolean(def); 255 | 256 | if (strcmp(def->defname, "init_command") == 0) 257 | opt->svr_init_command = defGetString(def); 258 | 259 | if (strcmp(def->defname, "max_blob_size") == 0) 260 | opt->max_blob_size = strtoul(defGetString(def), NULL, 0); 261 | 262 | if (strcmp(def->defname, "use_remote_estimate") == 0) 263 | opt->use_remote_estimate = defGetBoolean(def); 264 | 265 | if (strcmp(def->defname, "fetch_size") == 0) 266 | opt->fetch_size = strtoul(defGetString(def), NULL, 10); 267 | 268 | if (strcmp(def->defname, "reconnect") == 0) 269 | opt->reconnect = defGetBoolean(def); 270 | 271 | if (strcmp(def->defname, "character_set") == 0) 272 | opt->character_set = defGetString(def); 273 | 274 | if (strcmp(def->defname, "mysql_default_file") == 0) 275 | opt->mysql_default_file = defGetString(def); 276 | 277 | if (strcmp(def->defname, "sql_mode") == 0) 278 | opt->sql_mode = defGetString(def); 279 | 280 | if (strcmp(def->defname, "ssl_key") == 0) 281 | opt->ssl_key = defGetString(def); 282 | 283 | if (strcmp(def->defname, "ssl_cert") == 0) 284 | opt->ssl_cert = defGetString(def); 285 | 286 | if (strcmp(def->defname, "ssl_ca") == 0) 287 | opt->ssl_ca = defGetString(def); 288 | 289 | if (strcmp(def->defname, "ssl_capath") == 0) 290 | opt->ssl_capath = defGetString(def); 291 | 292 | if (strcmp(def->defname, "ssl_cipher") == 0) 293 | opt->ssl_cipher = defGetString(def); 294 | } 295 | 296 | /* Default values, if required */ 297 | if (!opt->svr_address) 298 | opt->svr_address = "127.0.0.1"; 299 | 300 | if (!opt->svr_port) 301 | opt->svr_port = MYSQL_SERVER_PORT; 302 | 303 | /* 304 | * When we don't have a table name or database name provided in the 305 | * FOREIGN TABLE options, then use a foreign table name as the target 306 | * table name and the namespace of the foreign table as a database name. 307 | */ 308 | if (f_table) 309 | { 310 | if (!opt->svr_table) 311 | opt->svr_table = get_rel_name(foreignoid); 312 | 313 | if (!opt->svr_database) 314 | opt->svr_database = get_namespace_name(get_rel_namespace(foreignoid)); 315 | } 316 | 317 | /* Default value for fetch_size */ 318 | if (!opt->fetch_size) 319 | opt->fetch_size = MYSQL_PREFETCH_ROWS; 320 | 321 | /* Default value for character_set */ 322 | if (!opt->character_set) 323 | opt->character_set = MYSQL_AUTODETECT_CHARSET_NAME; 324 | /* Special value provided for existing behavior */ 325 | else if (strcmp(opt->character_set, "PGDatabaseEncoding") == 0) 326 | opt->character_set = (char *) GetDatabaseEncodingName(); 327 | 328 | /* Default value for sql_mode */ 329 | if (!opt->sql_mode) 330 | opt->sql_mode = "ANSI_QUOTES"; 331 | 332 | return opt; 333 | } 334 | -------------------------------------------------------------------------------- /expected/server_options.out: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | -- Before running this file User must create database mysql_fdw_regress on 6 | -- MySQL with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 7 | -- and ran mysql_init.sh file to create tables. 8 | \c contrib_regression 9 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 10 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 11 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 12 | CREATE USER MAPPING FOR public SERVER mysql_svr 13 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 14 | -- Validate extension, server and mapping details 15 | CREATE OR REPLACE FUNCTION show_details(host TEXT, port TEXT, uid TEXT, pwd TEXT) RETURNS int AS $$ 16 | DECLARE 17 | ext TEXT; 18 | srv TEXT; 19 | sopts TEXT; 20 | uopts TEXT; 21 | BEGIN 22 | SELECT e.fdwname, srvname, array_to_string(s.srvoptions, ','), array_to_string(u.umoptions, ',') 23 | INTO ext, srv, sopts, uopts 24 | FROM pg_foreign_data_wrapper e LEFT JOIN pg_foreign_server s ON e.oid = s.srvfdw LEFT JOIN pg_user_mapping u ON s.oid = u.umserver 25 | WHERE e.fdwname = 'mysql_fdw' 26 | ORDER BY 1, 2, 3, 4; 27 | 28 | raise notice 'Extension : %', ext; 29 | raise notice 'Server : %', srv; 30 | 31 | IF strpos(sopts, host) <> 0 AND strpos(sopts, port) <> 0 THEN 32 | raise notice 'Server_Options : matched'; 33 | END IF; 34 | 35 | IF strpos(uopts, uid) <> 0 AND strpos(uopts, pwd) <> 0 THEN 36 | raise notice 'User_Mapping_Options : matched'; 37 | END IF; 38 | 39 | return 1; 40 | END; 41 | $$ language plpgsql; 42 | SELECT show_details(:MYSQL_HOST, :MYSQL_PORT, :MYSQL_USER_NAME, :MYSQL_PASS); 43 | NOTICE: Extension : mysql_fdw 44 | NOTICE: Server : mysql_svr 45 | NOTICE: Server_Options : matched 46 | NOTICE: User_Mapping_Options : matched 47 | show_details 48 | -------------- 49 | 1 50 | (1 row) 51 | 52 | -- Create foreign table and perform basic SQL operations 53 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 54 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 55 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 56 | a | b 57 | ---+--- 58 | 1 | 1 59 | (1 row) 60 | 61 | INSERT INTO f_mysql_test (a, b) VALUES (2, 2); 62 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 63 | a | b 64 | ---+--- 65 | 1 | 1 66 | 2 | 2 67 | (2 rows) 68 | 69 | UPDATE f_mysql_test SET b = 3 WHERE a = 2; 70 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 71 | a | b 72 | ---+--- 73 | 1 | 1 74 | 2 | 3 75 | (2 rows) 76 | 77 | DELETE FROM f_mysql_test WHERE a = 2; 78 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 79 | a | b 80 | ---+--- 81 | 1 | 1 82 | (1 row) 83 | 84 | DROP FOREIGN TABLE f_mysql_test; 85 | DROP USER MAPPING FOR public SERVER mysql_svr; 86 | DROP SERVER mysql_svr; 87 | -- Server with init_command. 88 | CREATE SERVER mysql_svr1 FOREIGN DATA WRAPPER mysql_fdw 89 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT, init_command 'create table init_command_check(a int)'); 90 | CREATE USER MAPPING FOR public SERVER mysql_svr1 91 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 92 | CREATE FOREIGN TABLE f_mysql_test (a int, b int) 93 | SERVER mysql_svr1 OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 94 | -- This will create init_command_check table in mysql_fdw_regress database. 95 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 96 | a | b 97 | ---+--- 98 | 1 | 1 99 | (1 row) 100 | 101 | -- init_command_check table created mysql_fdw_regress database can be verified 102 | -- by creating corresponding foreign table here. 103 | CREATE FOREIGN TABLE f_init_command_check(a int) 104 | SERVER mysql_svr1 OPTIONS (dbname 'mysql_fdw_regress', table_name 'init_command_check'); 105 | SELECT a FROM f_init_command_check ORDER BY 1; 106 | a 107 | --- 108 | (0 rows) 109 | 110 | -- Changing init_command to drop init_command_check table from 111 | -- mysql_fdw_regress database 112 | ALTER SERVER mysql_svr1 OPTIONS (SET init_command 'drop table init_command_check'); 113 | SELECT a, b FROM f_mysql_test; 114 | a | b 115 | ---+--- 116 | 1 | 1 117 | (1 row) 118 | 119 | DROP FOREIGN TABLE f_init_command_check; 120 | DROP FOREIGN TABLE f_mysql_test; 121 | DROP USER MAPPING FOR public SERVER mysql_svr1; 122 | DROP SERVER mysql_svr1; 123 | -- Server with use_remote_estimate. 124 | CREATE SERVER mysql_svr1 FOREIGN DATA WRAPPER mysql_fdw 125 | OPTIONS(host :MYSQL_HOST, port :MYSQL_PORT, use_remote_estimate 'TRUE'); 126 | CREATE USER MAPPING FOR public SERVER mysql_svr1 127 | OPTIONS(username :MYSQL_USER_NAME, password :MYSQL_PASS); 128 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 129 | SERVER mysql_svr1 OPTIONS(dbname 'mysql_fdw_regress', table_name 'mysql_test'); 130 | -- Below explain will return actual rows from MySQL, but keeping costs off 131 | -- here for consistent regression result. 132 | EXPLAIN (VERBOSE, COSTS OFF) SELECT a FROM f_mysql_test WHERE a < 2 ORDER BY 1; 133 | QUERY PLAN 134 | ------------------------------------------------------------------------------------------------------------------ 135 | Foreign Scan on public.f_mysql_test 136 | Output: a 137 | Remote query: SELECT `a` FROM `mysql_fdw_regress`.`mysql_test` WHERE ((`a` < 2)) ORDER BY `a` IS NULL, `a` ASC 138 | (3 rows) 139 | 140 | DROP FOREIGN TABLE f_mysql_test; 141 | DROP USER MAPPING FOR public SERVER mysql_svr1; 142 | DROP SERVER mysql_svr1; 143 | -- Create server with secure_auth. 144 | CREATE SERVER mysql_svr1 FOREIGN DATA WRAPPER mysql_fdw 145 | OPTIONS(host :MYSQL_HOST, port :MYSQL_PORT, secure_auth 'FALSE'); 146 | CREATE USER MAPPING FOR public SERVER mysql_svr1 147 | OPTIONS(username :MYSQL_USER_NAME, password :MYSQL_PASS); 148 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 149 | SERVER mysql_svr1 OPTIONS(dbname 'mysql_fdw_regress', table_name 'mysql_test'); 150 | -- Below should fail with Warning of secure_auth is false. 151 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 152 | WARNING: MySQL secure authentication is off 153 | a | b 154 | ---+--- 155 | 1 | 1 156 | (1 row) 157 | 158 | DROP FOREIGN TABLE f_mysql_test; 159 | DROP USER MAPPING FOR public SERVER mysql_svr1; 160 | DROP SERVER mysql_svr1; 161 | -- FDW-335: Support for fetch_size option at server level and table level. 162 | CREATE SERVER fetch101 FOREIGN DATA WRAPPER mysql_fdw 163 | OPTIONS( fetch_size '101' ); 164 | SELECT count(*) 165 | FROM pg_foreign_server 166 | WHERE srvname = 'fetch101' 167 | AND srvoptions @> array['fetch_size=101']; 168 | count 169 | ------- 170 | 1 171 | (1 row) 172 | 173 | ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' ); 174 | SELECT count(*) 175 | FROM pg_foreign_server 176 | WHERE srvname = 'fetch101' 177 | AND srvoptions @> array['fetch_size=101']; 178 | count 179 | ------- 180 | 0 181 | (1 row) 182 | 183 | SELECT count(*) 184 | FROM pg_foreign_server 185 | WHERE srvname = 'fetch101' 186 | AND srvoptions @> array['fetch_size=202']; 187 | count 188 | ------- 189 | 1 190 | (1 row) 191 | 192 | CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 193 | OPTIONS ( fetch_size '30000' ); 194 | SELECT COUNT(*) 195 | FROM pg_foreign_table 196 | WHERE ftrelid = 'table30000'::regclass 197 | AND ftoptions @> array['fetch_size=30000']; 198 | count 199 | ------- 200 | 1 201 | (1 row) 202 | 203 | ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000'); 204 | SELECT COUNT(*) 205 | FROM pg_foreign_table 206 | WHERE ftrelid = 'table30000'::regclass 207 | AND ftoptions @> array['fetch_size=30000']; 208 | count 209 | ------- 210 | 0 211 | (1 row) 212 | 213 | SELECT COUNT(*) 214 | FROM pg_foreign_table 215 | WHERE ftrelid = 'table30000'::regclass 216 | AND ftoptions @> array['fetch_size=60000']; 217 | count 218 | ------- 219 | 1 220 | (1 row) 221 | 222 | -- Make sure that changing the table level fetch-size value did not change the 223 | -- server level value. 224 | SELECT count(*) 225 | FROM pg_foreign_server 226 | WHERE srvname = 'fetch101' 227 | AND srvoptions @> array['fetch_size=202']; 228 | count 229 | ------- 230 | 1 231 | (1 row) 232 | 233 | -- Negative test cases for fetch_size option, should error out. 234 | ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '-60000'); 235 | ERROR: "fetch_size" requires an integer value between 1 to 18446744073709551615 236 | ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '123abc'); 237 | ERROR: "fetch_size" requires an integer value between 1 to 18446744073709551615 238 | ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '999999999999999999999'); 239 | ERROR: "fetch_size" requires an integer value between 1 to 18446744073709551615 240 | -- Cleanup fetch_size test objects. 241 | DROP FOREIGN TABLE table30000; 242 | DROP SERVER fetch101; 243 | -- FDW-350: Support for reconnect option at server level. 244 | CREATE SERVER reconnect1 FOREIGN DATA WRAPPER mysql_fdw 245 | OPTIONS( reconnect 'true' ); 246 | SELECT count(*) 247 | FROM pg_foreign_server 248 | WHERE srvname = 'reconnect1' 249 | AND srvoptions @> array['reconnect=true']; 250 | count 251 | ------- 252 | 1 253 | (1 row) 254 | 255 | ALTER SERVER reconnect1 OPTIONS( SET reconnect 'false' ); 256 | SELECT count(*) 257 | FROM pg_foreign_server 258 | WHERE srvname = 'reconnect1' 259 | AND srvoptions @> array['reconnect=false']; 260 | count 261 | ------- 262 | 1 263 | (1 row) 264 | 265 | -- Negative test case for reconnect option, should error out. 266 | ALTER SERVER reconnect1 OPTIONS ( SET reconnect 'abc1' ); 267 | ERROR: reconnect requires a Boolean value 268 | -- Cleanup reconnect option test objects. 269 | DROP SERVER reconnect1; 270 | -- FDW-404: Support for character_set option at server level. 271 | CREATE SERVER charset101 FOREIGN DATA WRAPPER mysql_fdw 272 | OPTIONS( character_set 'utf8' ); 273 | SELECT count(*) 274 | FROM pg_foreign_server 275 | WHERE srvname = 'charset101' 276 | AND srvoptions @> array['character_set=utf8']; 277 | count 278 | ------- 279 | 1 280 | (1 row) 281 | 282 | ALTER SERVER charset101 OPTIONS( SET character_set 'latin' ); 283 | SELECT count(*) 284 | FROM pg_foreign_server 285 | WHERE srvname = 'charset101' 286 | AND srvoptions @> array['character_set=latin']; 287 | count 288 | ------- 289 | 1 290 | (1 row) 291 | 292 | -- Cleanup character_set test objects. 293 | DROP SERVER charset101; 294 | -- Cleanup 295 | DROP EXTENSION mysql_fdw; 296 | -------------------------------------------------------------------------------- /sql/pushdown.sql: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | 6 | -- Before running this file User must create database mysql_fdw_regress on 7 | -- mysql with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 8 | -- and ran mysql_init.sh file to create tables. 9 | 10 | \c contrib_regression 11 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 12 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 13 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 14 | CREATE USER MAPPING FOR public SERVER mysql_svr 15 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 16 | 17 | -- Create foreign tables 18 | CREATE FOREIGN TABLE f_test_tbl1 (c1 INTEGER, c2 VARCHAR(10), c3 CHAR(9), c4 BIGINT, c5 pg_catalog.Date, c6 DECIMAL, c7 INTEGER, c8 SMALLINT) 19 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl1'); 20 | CREATE FOREIGN TABLE f_test_tbl2 (c1 INTEGER, c2 VARCHAR(14), c3 VARCHAR(13)) 21 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl2'); 22 | 23 | -- Insert data in mysql db using foreign tables 24 | INSERT INTO f_test_tbl1 VALUES (100, 'EMP1', 'ADMIN', 1300, '1980-12-17', 800.23, NULL, 20); 25 | INSERT INTO f_test_tbl1 VALUES (200, 'EMP2', 'SALESMAN', 600, '1981-02-20', 1600.00, 300, 30); 26 | INSERT INTO f_test_tbl1 VALUES (300, 'EMP3', 'SALESMAN', 600, '1981-02-22', 1250, 500, 30); 27 | INSERT INTO f_test_tbl1 VALUES (400, 'EMP4', 'MANAGER', 900, '1981-04-02', 2975.12, NULL, 20); 28 | INSERT INTO f_test_tbl1 VALUES (500, 'EMP5', 'SALESMAN', 600, '1981-09-28', 1250, 1400, 30); 29 | INSERT INTO f_test_tbl1 VALUES (600, 'EMP6', 'MANAGER', 900, '1981-05-01', 2850, NULL, 30); 30 | INSERT INTO f_test_tbl1 VALUES (700, 'EMP7', 'MANAGER', 900, '1981-06-09', 2450.45, NULL, 10); 31 | INSERT INTO f_test_tbl1 VALUES (800, 'EMP8', 'FINANCE', 400, '1987-04-19', 3000, NULL, 20); 32 | INSERT INTO f_test_tbl1 VALUES (900, 'EMP9', 'HEAD', NULL, '1981-11-17', 5000, NULL, 10); 33 | INSERT INTO f_test_tbl1 VALUES (1000, 'EMP10', 'SALESMAN', 600, '1980-09-08', 1500, 0, 30); 34 | INSERT INTO f_test_tbl1 VALUES (1100, 'EMP11', 'ADMIN', 800, '1987-05-23', 1100, NULL, 20); 35 | INSERT INTO f_test_tbl1 VALUES (1200, 'EMP12', 'ADMIN', 600, '1981-12-03', 950, NULL, 30); 36 | INSERT INTO f_test_tbl1 VALUES (1300, 'EMP13', 'FINANCE', 400, '1981-12-03', 3000, NULL, 20); 37 | INSERT INTO f_test_tbl1 VALUES (1400, 'EMP14', 'ADMIN', 700, '1982-01-23', 1300, NULL, 10); 38 | INSERT INTO f_test_tbl2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 39 | INSERT INTO f_test_tbl2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 40 | INSERT INTO f_test_tbl2 VALUES(30, 'SALES', 'MUMBAI'); 41 | INSERT INTO f_test_tbl2 VALUES(40, 'HR', 'NAGPUR'); 42 | 43 | SET datestyle TO ISO; 44 | 45 | -- WHERE clause pushdown 46 | 47 | EXPLAIN (VERBOSE, COSTS FALSE) 48 | SELECT c1, c2, c6 AS "salary", c8 FROM f_test_tbl1 e 49 | WHERE c6 IN (800,2450) 50 | ORDER BY c1; 51 | SELECT c1, c2, c6 AS "salary", c8 FROM f_test_tbl1 e 52 | WHERE c6 IN (800,2450) 53 | ORDER BY c1; 54 | 55 | EXPLAIN (VERBOSE, COSTS FALSE) 56 | SELECT * FROM f_test_tbl1 e 57 | WHERE c6 > 3000 58 | ORDER BY c1; 59 | SELECT * FROM f_test_tbl1 e 60 | WHERE c6 > 3000 61 | ORDER BY c1; 62 | 63 | EXPLAIN (VERBOSE, COSTS FALSE) 64 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 65 | WHERE c6 = 1500 66 | ORDER BY c1; 67 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 68 | WHERE c6 = 1500 69 | ORDER BY c1; 70 | 71 | EXPLAIN (VERBOSE, COSTS FALSE) 72 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 73 | WHERE c6 BETWEEN 1000 AND 4000 74 | ORDER BY c1; 75 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 76 | WHERE c6 BETWEEN 1000 AND 4000 77 | ORDER BY c1; 78 | 79 | EXPLAIN (VERBOSE, COSTS FALSE) 80 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 81 | WHERE c2 IS NOT NULL 82 | ORDER BY c1; 83 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 84 | WHERE c2 IS NOT NULL 85 | ORDER BY c1; 86 | 87 | EXPLAIN (VERBOSE, COSTS FALSE) 88 | SELECT * FROM f_test_tbl1 e 89 | WHERE c5 <= '1980-12-17' 90 | ORDER BY c1; 91 | SELECT * FROM f_test_tbl1 e 92 | WHERE c5 <= '1980-12-17' 93 | ORDER BY c1; 94 | 95 | EXPLAIN (VERBOSE, COSTS FALSE) 96 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 97 | WHERE c2 IN ('EMP6', 'EMP12', 'EMP5') 98 | ORDER BY c1; 99 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 100 | WHERE c2 IN ('EMP6', 'EMP12', 'EMP5') 101 | ORDER BY c1; 102 | 103 | EXPLAIN (VERBOSE, COSTS FALSE) 104 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 105 | WHERE c2 IN ('EMP6', 'EMP12', 'EMP5') 106 | ORDER BY c1; 107 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 108 | WHERE c2 IN ('EMP6', 'EMP12', 'EMP5') 109 | ORDER BY c1; 110 | 111 | EXPLAIN (VERBOSE, COSTS FALSE) 112 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 113 | WHERE c3 LIKE 'SALESMAN' 114 | ORDER BY c1; 115 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 116 | WHERE c3 LIKE 'SALESMAN' 117 | ORDER BY c1; 118 | 119 | EXPLAIN (VERBOSE, COSTS FALSE) 120 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 121 | WHERE c3 LIKE 'MANA%' 122 | ORDER BY c1; 123 | SELECT c1, c2, c6, c8 FROM f_test_tbl1 e 124 | WHERE c3 LIKE 'MANA%' 125 | ORDER BY c1; 126 | 127 | 128 | -- FDW-516: IS [NOT] DISTINCT FROM clause should deparse correctly. 129 | 130 | CREATE FOREIGN TABLE f_distinct_test (id int, c1 int, c2 int, c3 text, c4 text) 131 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'distinct_test'); 132 | INSERT INTO f_distinct_test VALUES 133 | (1, 1, 1, 'abc', 'abc'), 134 | (2, 2, NULL, 'abc', 'NULL'), 135 | (3, NULL, NULL, 'NULL', 'NULL'), 136 | (4, 3, 4, 'abc', 'pqr'), 137 | (5, 4, 5, 'abc', 'abc'), 138 | (6, 5, 5, 'abc', 'pqr'); 139 | SELECT * FROM f_distinct_test ORDER BY id; 140 | 141 | EXPLAIN (VERBOSE, COSTS FALSE) 142 | SELECT * FROM f_distinct_test WHERE (c1) IS DISTINCT FROM (c2) 143 | ORDER BY id; 144 | SELECT * FROM f_distinct_test WHERE (c1) IS DISTINCT FROM (c2) 145 | ORDER BY id; 146 | 147 | EXPLAIN (VERBOSE, COSTS FALSE) 148 | SELECT * FROM f_distinct_test WHERE (c1) IS NOT DISTINCT FROM (c2) 149 | ORDER BY id; 150 | SELECT * FROM f_distinct_test WHERE (c1) IS NOT DISTINCT FROM (c2) 151 | ORDER BY id; 152 | 153 | EXPLAIN (VERBOSE, COSTS FALSE) 154 | SELECT * FROM f_distinct_test WHERE (c3) IS DISTINCT FROM (c4) 155 | ORDER BY id; 156 | SELECT * FROM f_distinct_test WHERE (c3) IS DISTINCT FROM (c4) 157 | ORDER BY id; 158 | 159 | EXPLAIN (VERBOSE, COSTS FALSE) 160 | SELECT * FROM f_distinct_test WHERE (c3) IS NOT DISTINCT FROM (c4) 161 | ORDER BY id; 162 | SELECT * FROM f_distinct_test WHERE (c3) IS NOT DISTINCT FROM (c4) 163 | ORDER BY id; 164 | 165 | EXPLAIN (VERBOSE, COSTS FALSE) 166 | SELECT * FROM f_distinct_test 167 | WHERE (c1) IS DISTINCT FROM (c2) and (c3) IS NOT DISTINCT FROM (c4) 168 | ORDER BY id; 169 | SELECT * FROM f_distinct_test 170 | WHERE (c1) IS DISTINCT FROM (c2) and (c3) IS NOT DISTINCT FROM (c4) 171 | ORDER BY id; 172 | 173 | EXPLAIN (VERBOSE, COSTS FALSE) 174 | SELECT * FROM f_distinct_test 175 | WHERE (c1) IS NOT DISTINCT FROM (c2) or (c3) IS DISTINCT FROM (c4) 176 | ORDER BY id; 177 | SELECT * FROM f_distinct_test 178 | WHERE (c1) IS NOT DISTINCT FROM (c2) or (c3) IS DISTINCT FROM (c4) 179 | ORDER BY id; 180 | 181 | EXPLAIN (VERBOSE, COSTS FALSE) 182 | SELECT * FROM f_distinct_test 183 | WHERE ((c1) IS NOT DISTINCT FROM (c2)) IS DISTINCT FROM ((c3) IS NOT DISTINCT FROM (c4)) 184 | ORDER BY id; 185 | SELECT * FROM f_distinct_test 186 | WHERE ((c1) IS NOT DISTINCT FROM (c2)) IS DISTINCT FROM ((c3) IS NOT DISTINCT FROM (c4)) 187 | ORDER BY id; 188 | 189 | EXPLAIN (VERBOSE, COSTS FALSE) 190 | SELECT * FROM f_distinct_test 191 | WHERE ((c1) IS DISTINCT FROM (c2)) IS NOT DISTINCT FROM ((c3) IS DISTINCT FROM (c4)) 192 | ORDER BY id; 193 | SELECT * FROM f_distinct_test 194 | WHERE ((c1) IS DISTINCT FROM (c2)) IS NOT DISTINCT FROM ((c3) IS DISTINCT FROM (c4)) 195 | ORDER BY id; 196 | 197 | EXPLAIN (VERBOSE, COSTS FALSE) 198 | SELECT * FROM f_distinct_test 199 | WHERE ((c1) IS NOT DISTINCT FROM (c2)) IS DISTINCT FROM ((c3) IS DISTINCT FROM (c4)) 200 | ORDER BY id; 201 | SELECT * FROM f_distinct_test 202 | WHERE ((c1) IS NOT DISTINCT FROM (c2)) IS DISTINCT FROM ((c3) IS DISTINCT FROM (c4)) 203 | ORDER BY id; 204 | 205 | EXPLAIN (VERBOSE, COSTS FALSE) 206 | SELECT * FROM f_distinct_test 207 | WHERE ((c1) IS DISTINCT FROM (c2)) IS NOT DISTINCT FROM ((c3) IS NOT DISTINCT FROM (c4)) 208 | ORDER BY id; 209 | SELECT * FROM f_distinct_test 210 | WHERE ((c1) IS DISTINCT FROM (c2)) IS NOT DISTINCT FROM ((c3) IS NOT DISTINCT FROM (c4)) 211 | ORDER BY id; 212 | 213 | EXPLAIN (VERBOSE, COSTS FALSE) 214 | SELECT * FROM f_distinct_test 215 | WHERE ((c1) IS DISTINCT FROM (c2)) IS DISTINCT FROM ((c3) IS NOT DISTINCT FROM (c4)) 216 | ORDER BY id; 217 | SELECT * FROM f_distinct_test 218 | WHERE ((c1) IS DISTINCT FROM (c2)) IS DISTINCT FROM ((c3) IS NOT DISTINCT FROM (c4)) 219 | ORDER BY id; 220 | 221 | EXPLAIN (VERBOSE, COSTS FALSE) 222 | SELECT * FROM f_distinct_test 223 | WHERE ((c1) IS NOT DISTINCT FROM (c2)) IS NOT DISTINCT FROM ((c3) IS DISTINCT FROM (c4)) 224 | ORDER BY id; 225 | SELECT * FROM f_distinct_test 226 | WHERE ((c1) IS NOT DISTINCT FROM (c2)) IS NOT DISTINCT FROM ((c3) IS DISTINCT FROM (c4)) 227 | ORDER BY id; 228 | 229 | 230 | -- FDW-562: Test ORDER BY with user defined operators. 231 | 232 | -- Create the operator family required for the test. 233 | CREATE OPERATOR PUBLIC.<^ ( 234 | LEFTARG = INT4, 235 | RIGHTARG = INT4, 236 | PROCEDURE = INT4EQ 237 | ); 238 | 239 | CREATE OPERATOR PUBLIC.=^ ( 240 | LEFTARG = INT4, 241 | RIGHTARG = INT4, 242 | PROCEDURE = INT4LT 243 | ); 244 | 245 | CREATE OPERATOR PUBLIC.>^ ( 246 | LEFTARG = INT4, 247 | RIGHTARG = INT4, 248 | PROCEDURE = INT4GT 249 | ); 250 | 251 | CREATE OPERATOR FAMILY my_op_family USING btree; 252 | 253 | CREATE FUNCTION MY_OP_CMP(A INT, B INT) RETURNS INT AS 254 | $$ BEGIN RETURN BTINT4CMP(A, B); END $$ LANGUAGE PLPGSQL; 255 | 256 | CREATE OPERATOR CLASS my_op_class FOR TYPE INT USING btree FAMILY my_op_family AS 257 | OPERATOR 1 PUBLIC.<^, 258 | OPERATOR 3 PUBLIC.=^, 259 | OPERATOR 5 PUBLIC.>^, 260 | FUNCTION 1 my_op_cmp(INT, INT); 261 | 262 | -- FDW-562: Test ORDER BY with user defined operators. 263 | -- User defined operators are not pushed down. 264 | EXPLAIN (COSTS FALSE, VERBOSE) 265 | SELECT * FROM f_test_tbl1 ORDER BY c1 USING OPERATOR(public.<^); 266 | 267 | EXPLAIN (COSTS FALSE, VERBOSE) 268 | SELECT MIN(c1) FROM f_test_tbl1 GROUP BY c4 ORDER BY 1 USING OPERATOR(public.<^); 269 | 270 | -- Cleanup 271 | DELETE FROM f_test_tbl1; 272 | DELETE FROM f_test_tbl2; 273 | DELETE FROM f_distinct_test; 274 | DROP OPERATOR CLASS my_op_class USING btree; 275 | DROP FUNCTION my_op_cmp(a INT, b INT); 276 | DROP OPERATOR FAMILY my_op_family USING btree; 277 | DROP OPERATOR public.>^(INT, INT); 278 | DROP OPERATOR public.=^(INT, INT); 279 | DROP OPERATOR public.<^(INT, INT); 280 | DROP FOREIGN TABLE f_test_tbl1; 281 | DROP FOREIGN TABLE f_test_tbl2; 282 | DROP FOREIGN TABLE f_distinct_test; 283 | DROP USER MAPPING FOR public SERVER mysql_svr; 284 | DROP SERVER mysql_svr; 285 | DROP EXTENSION mysql_fdw; 286 | -------------------------------------------------------------------------------- /expected/limit_offset_pushdown_1.out: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | -- Before running this file User must create database mysql_fdw_regress on 6 | -- mysql with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 7 | -- and ran mysql_init.sh file to create tables. 8 | \c contrib_regression 9 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 10 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 11 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 12 | CREATE USER MAPPING FOR public SERVER mysql_svr 13 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 14 | -- Create foreign table 15 | CREATE FOREIGN TABLE f_test_tbl2 (c1 INTEGER, c2 VARCHAR(14), c3 VARCHAR(13)) 16 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl2'); 17 | INSERT INTO f_test_tbl2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 18 | INSERT INTO f_test_tbl2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 19 | INSERT INTO f_test_tbl2 VALUES(30, 'SALES', 'MUMBAI'); 20 | INSERT INTO f_test_tbl2 VALUES(40, 'HR', 'NAGPUR'); 21 | INSERT INTO f_test_tbl2 VALUES(50, 'IT', 'PUNE'); 22 | INSERT INTO f_test_tbl2 VALUES(60, 'DB SERVER', 'PUNE'); 23 | SELECT * FROM f_test_tbl2 ORDER BY 1; 24 | c1 | c2 | c3 25 | ----+----------------+---------- 26 | 10 | DEVELOPMENT | PUNE 27 | 20 | ADMINISTRATION | BANGLORE 28 | 30 | SALES | MUMBAI 29 | 40 | HR | NAGPUR 30 | 50 | IT | PUNE 31 | 60 | DB SERVER | PUNE 32 | (6 rows) 33 | 34 | -- LIMIT/OFFSET pushdown. 35 | -- Limit with Offset should get pushdown. 36 | EXPLAIN (VERBOSE, COSTS FALSE) 37 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET 2; 38 | QUERY PLAN 39 | ------------------------------------------------------------------------------------------------------------------------------- 40 | Foreign Scan on public.f_test_tbl2 41 | Output: c1, c2, c3 42 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 3 OFFSET 2 43 | (3 rows) 44 | 45 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET 2; 46 | c1 | c2 | c3 47 | ----+-------+-------- 48 | 30 | SALES | MUMBAI 49 | 40 | HR | NAGPUR 50 | 50 | IT | PUNE 51 | (3 rows) 52 | 53 | -- Only Limit should get pushdown. 54 | EXPLAIN (VERBOSE, COSTS FALSE) 55 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3; 56 | QUERY PLAN 57 | ---------------------------------------------------------------------------------------------------------------------- 58 | Foreign Scan on public.f_test_tbl2 59 | Output: c1, c2, c3 60 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 3 61 | (3 rows) 62 | 63 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3; 64 | c1 | c2 | c3 65 | ----+----------------+---------- 66 | 10 | DEVELOPMENT | PUNE 67 | 20 | ADMINISTRATION | BANGLORE 68 | 30 | SALES | MUMBAI 69 | (3 rows) 70 | 71 | -- Expression in Limit clause. 72 | EXPLAIN (VERBOSE, COSTS FALSE) 73 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT round(3.2) OFFSET 2; 74 | QUERY PLAN 75 | ------------------------------------------------------------------------------------------------------------------------------- 76 | Foreign Scan on public.f_test_tbl2 77 | Output: c1, c2, c3 78 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 3 OFFSET 2 79 | (3 rows) 80 | 81 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT round(3.2) OFFSET 2; 82 | c1 | c2 | c3 83 | ----+-------+-------- 84 | 30 | SALES | MUMBAI 85 | 40 | HR | NAGPUR 86 | 50 | IT | PUNE 87 | (3 rows) 88 | 89 | -- Only Offset without Limit should not get pushdown. 90 | EXPLAIN (VERBOSE, COSTS FALSE) 91 | SELECT * FROM f_test_tbl2 ORDER BY 1 OFFSET 2; 92 | QUERY PLAN 93 | -------------------------------------------------------------------------------------------------------------------- 94 | Limit 95 | Output: c1, c2, c3 96 | -> Foreign Scan on public.f_test_tbl2 97 | Output: c1, c2, c3 98 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 99 | (5 rows) 100 | 101 | SELECT * FROM f_test_tbl2 ORDER BY 1 OFFSET 2; 102 | c1 | c2 | c3 103 | ----+-----------+-------- 104 | 30 | SALES | MUMBAI 105 | 40 | HR | NAGPUR 106 | 50 | IT | PUNE 107 | 60 | DB SERVER | PUNE 108 | (4 rows) 109 | 110 | -- Limit ALL 111 | EXPLAIN (VERBOSE, COSTS FALSE) 112 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT ALL; 113 | QUERY PLAN 114 | -------------------------------------------------------------------------------------------------------------- 115 | Foreign Scan on public.f_test_tbl2 116 | Output: c1, c2, c3 117 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 118 | (3 rows) 119 | 120 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT ALL; 121 | c1 | c2 | c3 122 | ----+----------------+---------- 123 | 10 | DEVELOPMENT | PUNE 124 | 20 | ADMINISTRATION | BANGLORE 125 | 30 | SALES | MUMBAI 126 | 40 | HR | NAGPUR 127 | 50 | IT | PUNE 128 | 60 | DB SERVER | PUNE 129 | (6 rows) 130 | 131 | -- Limit NULL 132 | EXPLAIN (VERBOSE, COSTS FALSE) 133 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL; 134 | QUERY PLAN 135 | -------------------------------------------------------------------------------------------------------------- 136 | Foreign Scan on public.f_test_tbl2 137 | Output: c1, c2, c3 138 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 139 | (3 rows) 140 | 141 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL; 142 | c1 | c2 | c3 143 | ----+----------------+---------- 144 | 10 | DEVELOPMENT | PUNE 145 | 20 | ADMINISTRATION | BANGLORE 146 | 30 | SALES | MUMBAI 147 | 40 | HR | NAGPUR 148 | 50 | IT | PUNE 149 | 60 | DB SERVER | PUNE 150 | (6 rows) 151 | 152 | EXPLAIN (VERBOSE, COSTS FALSE) 153 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL OFFSET 2; 154 | QUERY PLAN 155 | -------------------------------------------------------------------------------------------------------------------- 156 | Limit 157 | Output: c1, c2, c3 158 | -> Foreign Scan on public.f_test_tbl2 159 | Output: c1, c2, c3 160 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 161 | (5 rows) 162 | 163 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL OFFSET 2; 164 | c1 | c2 | c3 165 | ----+-----------+-------- 166 | 30 | SALES | MUMBAI 167 | 40 | HR | NAGPUR 168 | 50 | IT | PUNE 169 | 60 | DB SERVER | PUNE 170 | (4 rows) 171 | 172 | -- Limit 0 and Offset 0 173 | EXPLAIN (VERBOSE, COSTS FALSE) 174 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0; 175 | QUERY PLAN 176 | ---------------------------------------------------------------------------------------------------------------------- 177 | Foreign Scan on public.f_test_tbl2 178 | Output: c1, c2, c3 179 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 0 180 | (3 rows) 181 | 182 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0; 183 | c1 | c2 | c3 184 | ----+----+---- 185 | (0 rows) 186 | 187 | EXPLAIN (VERBOSE, COSTS FALSE) 188 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0 OFFSET 0; 189 | QUERY PLAN 190 | ------------------------------------------------------------------------------------------------------------------------------- 191 | Foreign Scan on public.f_test_tbl2 192 | Output: c1, c2, c3 193 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 0 OFFSET 0 194 | (3 rows) 195 | 196 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0 OFFSET 0; 197 | c1 | c2 | c3 198 | ----+----+---- 199 | (0 rows) 200 | 201 | -- Offset NULL. 202 | EXPLAIN (VERBOSE, COSTS FALSE) 203 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET NULL; 204 | QUERY PLAN 205 | ---------------------------------------------------------------------------------------------------------------------- 206 | Foreign Scan on public.f_test_tbl2 207 | Output: c1, c2, c3 208 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 3 209 | (3 rows) 210 | 211 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET NULL; 212 | c1 | c2 | c3 213 | ----+----------------+---------- 214 | 10 | DEVELOPMENT | PUNE 215 | 20 | ADMINISTRATION | BANGLORE 216 | 30 | SALES | MUMBAI 217 | (3 rows) 218 | 219 | -- Limit with placeholder. 220 | EXPLAIN (VERBOSE, COSTS FALSE) 221 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (SELECT COUNT(*) FROM f_test_tbl2); 222 | QUERY PLAN 223 | ---------------------------------------------------------------------------------------------------------------------- 224 | Foreign Scan on public.f_test_tbl2 225 | Output: f_test_tbl2.c1, f_test_tbl2.c2, f_test_tbl2.c3 226 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT ? 227 | InitPlan 1 228 | -> Foreign Scan 229 | Output: (count(*)) 230 | Relations: Aggregate on (mysql_fdw_regress.f_test_tbl2) 231 | Remote query: SELECT count(*) FROM `mysql_fdw_regress`.`test_tbl2` 232 | (8 rows) 233 | 234 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (SELECT COUNT(*) FROM f_test_tbl2); 235 | c1 | c2 | c3 236 | ----+----------------+---------- 237 | 10 | DEVELOPMENT | PUNE 238 | 20 | ADMINISTRATION | BANGLORE 239 | 30 | SALES | MUMBAI 240 | 40 | HR | NAGPUR 241 | 50 | IT | PUNE 242 | 60 | DB SERVER | PUNE 243 | (6 rows) 244 | 245 | -- Limit with expression, should not pushdown. 246 | EXPLAIN (VERBOSE, COSTS FALSE) 247 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (10 - (SELECT COUNT(*) FROM f_test_tbl2)); 248 | QUERY PLAN 249 | -------------------------------------------------------------------------------------------------------------------- 250 | Limit 251 | Output: f_test_tbl2.c1, f_test_tbl2.c2, f_test_tbl2.c3 252 | InitPlan 1 253 | -> Foreign Scan 254 | Output: (count(*)) 255 | Relations: Aggregate on (mysql_fdw_regress.f_test_tbl2) 256 | Remote query: SELECT count(*) FROM `mysql_fdw_regress`.`test_tbl2` 257 | -> Foreign Scan on public.f_test_tbl2 258 | Output: f_test_tbl2.c1, f_test_tbl2.c2, f_test_tbl2.c3 259 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 260 | (10 rows) 261 | 262 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (10 - (SELECT COUNT(*) FROM f_test_tbl2)); 263 | c1 | c2 | c3 264 | ----+----------------+---------- 265 | 10 | DEVELOPMENT | PUNE 266 | 20 | ADMINISTRATION | BANGLORE 267 | 30 | SALES | MUMBAI 268 | 40 | HR | NAGPUR 269 | (4 rows) 270 | 271 | DELETE FROM f_test_tbl2; 272 | DROP FOREIGN TABLE f_test_tbl2; 273 | DROP USER MAPPING FOR public SERVER mysql_svr; 274 | DROP SERVER mysql_svr; 275 | DROP EXTENSION mysql_fdw; 276 | -------------------------------------------------------------------------------- /expected/limit_offset_pushdown.out: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | -- Before running this file User must create database mysql_fdw_regress on 6 | -- mysql with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 7 | -- and ran mysql_init.sh file to create tables. 8 | \c contrib_regression 9 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 10 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 11 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 12 | CREATE USER MAPPING FOR public SERVER mysql_svr 13 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 14 | -- Create foreign table 15 | CREATE FOREIGN TABLE f_test_tbl2 (c1 INTEGER, c2 VARCHAR(14), c3 VARCHAR(13)) 16 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl2'); 17 | INSERT INTO f_test_tbl2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 18 | INSERT INTO f_test_tbl2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 19 | INSERT INTO f_test_tbl2 VALUES(30, 'SALES', 'MUMBAI'); 20 | INSERT INTO f_test_tbl2 VALUES(40, 'HR', 'NAGPUR'); 21 | INSERT INTO f_test_tbl2 VALUES(50, 'IT', 'PUNE'); 22 | INSERT INTO f_test_tbl2 VALUES(60, 'DB SERVER', 'PUNE'); 23 | SELECT * FROM f_test_tbl2 ORDER BY 1; 24 | c1 | c2 | c3 25 | ----+----------------+---------- 26 | 10 | DEVELOPMENT | PUNE 27 | 20 | ADMINISTRATION | BANGLORE 28 | 30 | SALES | MUMBAI 29 | 40 | HR | NAGPUR 30 | 50 | IT | PUNE 31 | 60 | DB SERVER | PUNE 32 | (6 rows) 33 | 34 | -- LIMIT/OFFSET pushdown. 35 | -- Limit with Offset should get pushdown. 36 | EXPLAIN (VERBOSE, COSTS FALSE) 37 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET 2; 38 | QUERY PLAN 39 | ------------------------------------------------------------------------------------------------------------------------------- 40 | Foreign Scan on public.f_test_tbl2 41 | Output: c1, c2, c3 42 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 3 OFFSET 2 43 | (3 rows) 44 | 45 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET 2; 46 | c1 | c2 | c3 47 | ----+-------+-------- 48 | 30 | SALES | MUMBAI 49 | 40 | HR | NAGPUR 50 | 50 | IT | PUNE 51 | (3 rows) 52 | 53 | -- Only Limit should get pushdown. 54 | EXPLAIN (VERBOSE, COSTS FALSE) 55 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3; 56 | QUERY PLAN 57 | ---------------------------------------------------------------------------------------------------------------------- 58 | Foreign Scan on public.f_test_tbl2 59 | Output: c1, c2, c3 60 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 3 61 | (3 rows) 62 | 63 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3; 64 | c1 | c2 | c3 65 | ----+----------------+---------- 66 | 10 | DEVELOPMENT | PUNE 67 | 20 | ADMINISTRATION | BANGLORE 68 | 30 | SALES | MUMBAI 69 | (3 rows) 70 | 71 | -- Expression in Limit clause. 72 | EXPLAIN (VERBOSE, COSTS FALSE) 73 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT round(3.2) OFFSET 2; 74 | QUERY PLAN 75 | ------------------------------------------------------------------------------------------------------------------------------- 76 | Foreign Scan on public.f_test_tbl2 77 | Output: c1, c2, c3 78 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 3 OFFSET 2 79 | (3 rows) 80 | 81 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT round(3.2) OFFSET 2; 82 | c1 | c2 | c3 83 | ----+-------+-------- 84 | 30 | SALES | MUMBAI 85 | 40 | HR | NAGPUR 86 | 50 | IT | PUNE 87 | (3 rows) 88 | 89 | -- Only Offset without Limit should not get pushdown. 90 | EXPLAIN (VERBOSE, COSTS FALSE) 91 | SELECT * FROM f_test_tbl2 ORDER BY 1 OFFSET 2; 92 | QUERY PLAN 93 | -------------------------------------------------------------------------------------------------------------------- 94 | Limit 95 | Output: c1, c2, c3 96 | -> Foreign Scan on public.f_test_tbl2 97 | Output: c1, c2, c3 98 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 99 | (5 rows) 100 | 101 | SELECT * FROM f_test_tbl2 ORDER BY 1 OFFSET 2; 102 | c1 | c2 | c3 103 | ----+-----------+-------- 104 | 30 | SALES | MUMBAI 105 | 40 | HR | NAGPUR 106 | 50 | IT | PUNE 107 | 60 | DB SERVER | PUNE 108 | (4 rows) 109 | 110 | -- Limit ALL 111 | EXPLAIN (VERBOSE, COSTS FALSE) 112 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT ALL; 113 | QUERY PLAN 114 | -------------------------------------------------------------------------------------------------------------- 115 | Foreign Scan on public.f_test_tbl2 116 | Output: c1, c2, c3 117 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 118 | (3 rows) 119 | 120 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT ALL; 121 | c1 | c2 | c3 122 | ----+----------------+---------- 123 | 10 | DEVELOPMENT | PUNE 124 | 20 | ADMINISTRATION | BANGLORE 125 | 30 | SALES | MUMBAI 126 | 40 | HR | NAGPUR 127 | 50 | IT | PUNE 128 | 60 | DB SERVER | PUNE 129 | (6 rows) 130 | 131 | -- Limit NULL 132 | EXPLAIN (VERBOSE, COSTS FALSE) 133 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL; 134 | QUERY PLAN 135 | -------------------------------------------------------------------------------------------------------------- 136 | Foreign Scan on public.f_test_tbl2 137 | Output: c1, c2, c3 138 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 139 | (3 rows) 140 | 141 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL; 142 | c1 | c2 | c3 143 | ----+----------------+---------- 144 | 10 | DEVELOPMENT | PUNE 145 | 20 | ADMINISTRATION | BANGLORE 146 | 30 | SALES | MUMBAI 147 | 40 | HR | NAGPUR 148 | 50 | IT | PUNE 149 | 60 | DB SERVER | PUNE 150 | (6 rows) 151 | 152 | EXPLAIN (VERBOSE, COSTS FALSE) 153 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL OFFSET 2; 154 | QUERY PLAN 155 | -------------------------------------------------------------------------------------------------------------------- 156 | Limit 157 | Output: c1, c2, c3 158 | -> Foreign Scan on public.f_test_tbl2 159 | Output: c1, c2, c3 160 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 161 | (5 rows) 162 | 163 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT NULL OFFSET 2; 164 | c1 | c2 | c3 165 | ----+-----------+-------- 166 | 30 | SALES | MUMBAI 167 | 40 | HR | NAGPUR 168 | 50 | IT | PUNE 169 | 60 | DB SERVER | PUNE 170 | (4 rows) 171 | 172 | -- Limit 0 and Offset 0 173 | EXPLAIN (VERBOSE, COSTS FALSE) 174 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0; 175 | QUERY PLAN 176 | ---------------------------------------------------------------------------------------------------------------------- 177 | Foreign Scan on public.f_test_tbl2 178 | Output: c1, c2, c3 179 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 0 180 | (3 rows) 181 | 182 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0; 183 | c1 | c2 | c3 184 | ----+----+---- 185 | (0 rows) 186 | 187 | EXPLAIN (VERBOSE, COSTS FALSE) 188 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0 OFFSET 0; 189 | QUERY PLAN 190 | ------------------------------------------------------------------------------------------------------------------------------- 191 | Foreign Scan on public.f_test_tbl2 192 | Output: c1, c2, c3 193 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 0 OFFSET 0 194 | (3 rows) 195 | 196 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 0 OFFSET 0; 197 | c1 | c2 | c3 198 | ----+----+---- 199 | (0 rows) 200 | 201 | -- Offset NULL. 202 | EXPLAIN (VERBOSE, COSTS FALSE) 203 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET NULL; 204 | QUERY PLAN 205 | ---------------------------------------------------------------------------------------------------------------------- 206 | Foreign Scan on public.f_test_tbl2 207 | Output: c1, c2, c3 208 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT 3 209 | (3 rows) 210 | 211 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT 3 OFFSET NULL; 212 | c1 | c2 | c3 213 | ----+----------------+---------- 214 | 10 | DEVELOPMENT | PUNE 215 | 20 | ADMINISTRATION | BANGLORE 216 | 30 | SALES | MUMBAI 217 | (3 rows) 218 | 219 | -- Limit with placeholder. 220 | EXPLAIN (VERBOSE, COSTS FALSE) 221 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (SELECT COUNT(*) FROM f_test_tbl2); 222 | QUERY PLAN 223 | ---------------------------------------------------------------------------------------------------------------------- 224 | Foreign Scan on public.f_test_tbl2 225 | Output: f_test_tbl2.c1, f_test_tbl2.c2, f_test_tbl2.c3 226 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC LIMIT ? 227 | InitPlan 1 (returns $0) 228 | -> Foreign Scan 229 | Output: (count(*)) 230 | Relations: Aggregate on (mysql_fdw_regress.f_test_tbl2) 231 | Remote query: SELECT count(*) FROM `mysql_fdw_regress`.`test_tbl2` 232 | (8 rows) 233 | 234 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (SELECT COUNT(*) FROM f_test_tbl2); 235 | c1 | c2 | c3 236 | ----+----------------+---------- 237 | 10 | DEVELOPMENT | PUNE 238 | 20 | ADMINISTRATION | BANGLORE 239 | 30 | SALES | MUMBAI 240 | 40 | HR | NAGPUR 241 | 50 | IT | PUNE 242 | 60 | DB SERVER | PUNE 243 | (6 rows) 244 | 245 | -- Limit with expression, should not pushdown. 246 | EXPLAIN (VERBOSE, COSTS FALSE) 247 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (10 - (SELECT COUNT(*) FROM f_test_tbl2)); 248 | QUERY PLAN 249 | -------------------------------------------------------------------------------------------------------------------- 250 | Limit 251 | Output: f_test_tbl2.c1, f_test_tbl2.c2, f_test_tbl2.c3 252 | InitPlan 1 (returns $0) 253 | -> Foreign Scan 254 | Output: (count(*)) 255 | Relations: Aggregate on (mysql_fdw_regress.f_test_tbl2) 256 | Remote query: SELECT count(*) FROM `mysql_fdw_regress`.`test_tbl2` 257 | -> Foreign Scan on public.f_test_tbl2 258 | Output: f_test_tbl2.c1, f_test_tbl2.c2, f_test_tbl2.c3 259 | Remote query: SELECT `c1`, `c2`, `c3` FROM `mysql_fdw_regress`.`test_tbl2` ORDER BY `c1` IS NULL, `c1` ASC 260 | (10 rows) 261 | 262 | SELECT * FROM f_test_tbl2 ORDER BY 1 LIMIT (10 - (SELECT COUNT(*) FROM f_test_tbl2)); 263 | c1 | c2 | c3 264 | ----+----------------+---------- 265 | 10 | DEVELOPMENT | PUNE 266 | 20 | ADMINISTRATION | BANGLORE 267 | 30 | SALES | MUMBAI 268 | 40 | HR | NAGPUR 269 | (4 rows) 270 | 271 | DELETE FROM f_test_tbl2; 272 | DROP FOREIGN TABLE f_test_tbl2; 273 | DROP USER MAPPING FOR public SERVER mysql_svr; 274 | DROP SERVER mysql_svr; 275 | DROP EXTENSION mysql_fdw; 276 | -------------------------------------------------------------------------------- /mysql_fdw_pushdown.config: -------------------------------------------------------------------------------- 1 | #----------------------------------------------------------------------------- 2 | # This file lists object as aggregates, functions, and operators are allowed 3 | # to push down to the remote server. Each entry should be on its line and 4 | # consists of two columns: the first is object type as ROUTINE (for functions, 5 | # aggregates, and procedures) or OPERATOR, and the second column is optionally 6 | # schema-qualified object names with their arguments. The exact form of the 7 | # second column can be formatted using the following query: 8 | # 9 | # For routines: 10 | # 11 | # SELECT pronamespace::regnamespace || '.' || oid::regprocedure FROM pg_proc 12 | # WHERE proname = '' 13 | # 14 | # And for operator: 15 | # 16 | # SELECT oprnamespace::regnamespace || '.' || oid::regoperator FROM pg_operator 17 | # WHERE oprname = '' 18 | # 19 | # Note: To identify objects uniquely, the name and/or its argument must be 20 | # schema-qualified. 21 | #----------------------------------------------------------------------------- 22 | ROUTINE pg_catalog.sum(bigint) 23 | ROUTINE pg_catalog.sum(smallint) 24 | ROUTINE pg_catalog.sum(integer) 25 | ROUTINE pg_catalog.sum(real) 26 | ROUTINE pg_catalog.sum(double precision) 27 | ROUTINE pg_catalog.sum(numeric) 28 | ROUTINE pg_catalog.avg(bigint) 29 | ROUTINE pg_catalog.avg(smallint) 30 | ROUTINE pg_catalog.avg(integer) 31 | ROUTINE pg_catalog.avg(real) 32 | ROUTINE pg_catalog.avg(double precision) 33 | ROUTINE pg_catalog.avg(numeric) 34 | ROUTINE pg_catalog.min(bigint) 35 | ROUTINE pg_catalog.min(smallint) 36 | ROUTINE pg_catalog.min(integer) 37 | ROUTINE pg_catalog.min(real) 38 | ROUTINE pg_catalog.min(double precision) 39 | ROUTINE pg_catalog.min(numeric) 40 | ROUTINE pg_catalog.min(oid) 41 | ROUTINE pg_catalog.min(character) 42 | ROUTINE pg_catalog.min(time without time zone) 43 | ROUTINE pg_catalog.min(time with time zone) 44 | ROUTINE pg_catalog.min(timestamp without time zone) 45 | ROUTINE pg_catalog.min(timestamp with time zone) 46 | ROUTINE pg_catalog.min(text) 47 | ROUTINE pg_catalog.min(anyenum) 48 | ROUTINE pg_catalog.min(pg_catalog.date) 49 | ROUTINE pg_catalog.max(bigint) 50 | ROUTINE pg_catalog.max(smallint) 51 | ROUTINE pg_catalog.max(integer) 52 | ROUTINE pg_catalog.max(real) 53 | ROUTINE pg_catalog.max(double precision) 54 | ROUTINE pg_catalog.max(numeric) 55 | ROUTINE pg_catalog.max(oid) 56 | ROUTINE pg_catalog.max(character) 57 | ROUTINE pg_catalog.max(time without time zone) 58 | ROUTINE pg_catalog.max(time with time zone) 59 | ROUTINE pg_catalog.max(timestamp without time zone) 60 | ROUTINE pg_catalog.max(timestamp with time zone) 61 | ROUTINE pg_catalog.max(text) 62 | ROUTINE pg_catalog.max(anyenum) 63 | ROUTINE pg_catalog.max(pg_catalog.date) 64 | ROUTINE pg_catalog.count() 65 | ROUTINE pg_catalog.count("any") 66 | ROUTINE pg_catalog.rank() 67 | ROUTINE pg_catalog.rank("any") 68 | ROUTINE pg_catalog.percentile_cont(double precision,double precision) 69 | ROUTINE pg_catalog.percentile_cont(double precision[],double precision) 70 | ROUTINE pg_catalog.stddev(bigint) 71 | ROUTINE pg_catalog.stddev(integer) 72 | ROUTINE pg_catalog.stddev(smallint) 73 | ROUTINE pg_catalog.stddev(real) 74 | ROUTINE pg_catalog.stddev(double precision) 75 | ROUTINE pg_catalog.stddev(numeric) 76 | ROUTINE pg_catalog.length(text) 77 | ROUTINE pg_catalog.length(character) 78 | ROUTINE pg_catalog.length(bit) 79 | ROUTINE pg_catalog.length(bytea) 80 | ROUTINE pg_catalog.length(bytea,name) 81 | ROUTINE pg_catalog.lower(text) 82 | ROUTINE pg_catalog.upper(text) 83 | ROUTINE pg_catalog.floor(numeric) 84 | ROUTINE pg_catalog.floor(double precision) 85 | ROUTINE pg_catalog.sqrt(numeric) 86 | ROUTINE pg_catalog.sqrt(double precision) 87 | ROUTINE pg_catalog.exp(numeric) 88 | ROUTINE pg_catalog.exp(double precision) 89 | ROUTINE pg_catalog.mod(integer,integer) 90 | ROUTINE pg_catalog.mod(numeric,numeric) 91 | ROUTINE pg_catalog.mod(smallint,smallint) 92 | ROUTINE pg_catalog.mod(bigint,bigint) 93 | ROUTINE pg_catalog.float8(numeric) 94 | ROUTINE pg_catalog.float8(smallint) 95 | ROUTINE pg_catalog.float8(integer) 96 | ROUTINE pg_catalog.float8(bigint) 97 | ROUTINE pg_catalog.float8(real) 98 | ROUTINE pg_catalog.int4(numeric) 99 | ROUTINE pg_catalog.int4(smallint) 100 | ROUTINE pg_catalog.int4(double precision) 101 | ROUTINE pg_catalog.int4(bigint) 102 | ROUTINE pg_catalog.int4(bit) 103 | ROUTINE pg_catalog.int4(boolean) 104 | ROUTINE pg_catalog.int4(real) 105 | ROUTINE pg_catalog."numeric"(bigint) 106 | ROUTINE pg_catalog."numeric"(integer) 107 | ROUTINE pg_catalog."numeric"(double precision) 108 | ROUTINE pg_catalog."numeric"(smallint) 109 | ROUTINE pg_catalog."numeric"(numeric,integer) 110 | ROUTINE pg_catalog."numeric"(real) 111 | OPERATOR pg_catalog.=(bigint,bigint) 112 | OPERATOR pg_catalog.=(integer,integer) 113 | OPERATOR pg_catalog.=(text,text) 114 | OPERATOR pg_catalog.=(smallint,integer) 115 | OPERATOR pg_catalog.=(bigint,integer) 116 | OPERATOR pg_catalog.=(numeric,numeric) 117 | OPERATOR pg_catalog.=(smallint,smallint) 118 | OPERATOR pg_catalog.=(double precision,double precision) 119 | OPERATOR pg_catalog.=(timestamp with time zone,timestamp with time zone) 120 | OPERATOR pg_catalog.=(oid,oid) 121 | OPERATOR pg_catalog.=(character,character) 122 | OPERATOR pg_catalog.=(time with time zone,time with time zone) 123 | OPERATOR pg_catalog.=(time without time zone,time without time zone) 124 | OPERATOR pg_catalog.=(timestamp without time zone,timestamp without time zone) 125 | OPERATOR pg_catalog.=(boolean,boolean) 126 | OPERATOR pg_catalog.=(bytea,bytea) 127 | OPERATOR pg_catalog.=(name,name) 128 | OPERATOR pg_catalog.=(real,real) 129 | OPERATOR pg_catalog.=(pg_catalog.date,pg_catalog.date) 130 | OPERATOR pg_catalog.=(bit,bit) 131 | OPERATOR pg_catalog.=(anyenum,anyenum) 132 | OPERATOR pg_catalog.>(bigint,bigint) 133 | OPERATOR pg_catalog.>(integer,integer) 134 | OPERATOR pg_catalog.>(text,text) 135 | OPERATOR pg_catalog.>(smallint,integer) 136 | OPERATOR pg_catalog.>(bigint,integer) 137 | OPERATOR pg_catalog.>(numeric,numeric) 138 | OPERATOR pg_catalog.>(boolean,boolean) 139 | OPERATOR pg_catalog.>(smallint,smallint) 140 | OPERATOR pg_catalog.>(double precision,double precision) 141 | OPERATOR pg_catalog.>(timestamp with time zone,timestamp with time zone) 142 | OPERATOR pg_catalog.>(oid,oid) 143 | OPERATOR pg_catalog.>(character,character) 144 | OPERATOR pg_catalog.>(time with time zone,time with time zone) 145 | OPERATOR pg_catalog.>(time without time zone,time without time zone) 146 | OPERATOR pg_catalog.>(timestamp without time zone,timestamp without time zone) 147 | OPERATOR pg_catalog.>(bytea,bytea) 148 | OPERATOR pg_catalog.>(name,name) 149 | OPERATOR pg_catalog.>(real,real) 150 | OPERATOR pg_catalog.>(pg_catalog.date,pg_catalog.date) 151 | OPERATOR pg_catalog.>(bit,bit) 152 | OPERATOR pg_catalog.>(anyenum,anyenum) 153 | OPERATOR pg_catalog.<(bigint,bigint) 154 | OPERATOR pg_catalog.<(integer,integer) 155 | OPERATOR pg_catalog.<(text,text) 156 | OPERATOR pg_catalog.<(smallint,integer) 157 | OPERATOR pg_catalog.<(smallint,smallint) 158 | OPERATOR pg_catalog.<(bigint,integer) 159 | OPERATOR pg_catalog.<(double precision,double precision) 160 | OPERATOR pg_catalog.<(numeric,numeric) 161 | OPERATOR pg_catalog.<(character,character) 162 | OPERATOR pg_catalog.<(boolean,boolean) 163 | OPERATOR pg_catalog.<(timestamp with time zone,timestamp with time zone) 164 | OPERATOR pg_catalog.<(oid,oid) 165 | OPERATOR pg_catalog.<(time with time zone,time with time zone) 166 | OPERATOR pg_catalog.<(time without time zone,time without time zone) 167 | OPERATOR pg_catalog.<(timestamp without time zone,timestamp without time zone) 168 | OPERATOR pg_catalog.<(bytea,bytea) 169 | OPERATOR pg_catalog.<(name,name) 170 | OPERATOR pg_catalog.<(real,real) 171 | OPERATOR pg_catalog.<(pg_catalog.date,pg_catalog.date) 172 | OPERATOR pg_catalog.<(bit,bit) 173 | OPERATOR pg_catalog.<(anyenum,anyenum) 174 | OPERATOR pg_catalog.>=(bigint,bigint) 175 | OPERATOR pg_catalog.>=(integer,integer) 176 | OPERATOR pg_catalog.>=(text,text) 177 | OPERATOR pg_catalog.>=(smallint,integer) 178 | OPERATOR pg_catalog.>=(bigint,integer) 179 | OPERATOR pg_catalog.>=(numeric,numeric) 180 | OPERATOR pg_catalog.>=(smallint,smallint) 181 | OPERATOR pg_catalog.>=(double precision,double precision) 182 | OPERATOR pg_catalog.>=(timestamp with time zone,timestamp with time zone) 183 | OPERATOR pg_catalog.>=(oid,oid) 184 | OPERATOR pg_catalog.>=(character,character) 185 | OPERATOR pg_catalog.>=(time with time zone,time with time zone) 186 | OPERATOR pg_catalog.>=(time without time zone,time without time zone) 187 | OPERATOR pg_catalog.>=(timestamp without time zone,timestamp without time zone) 188 | OPERATOR pg_catalog.>=(boolean,boolean) 189 | OPERATOR pg_catalog.>=(bytea,bytea) 190 | OPERATOR pg_catalog.>=(name,name) 191 | OPERATOR pg_catalog.>=(real,real) 192 | OPERATOR pg_catalog.>=(pg_catalog.date,pg_catalog.date) 193 | OPERATOR pg_catalog.>=(bit,bit) 194 | OPERATOR pg_catalog.>=(anyenum,anyenum) 195 | OPERATOR pg_catalog.<=(bigint,bigint) 196 | OPERATOR pg_catalog.<=(integer,integer) 197 | OPERATOR pg_catalog.<=(text,text) 198 | OPERATOR pg_catalog.<=(smallint,integer) 199 | OPERATOR pg_catalog.<=(bigint,integer) 200 | OPERATOR pg_catalog.<=(numeric,numeric) 201 | OPERATOR pg_catalog.<=(smallint,smallint) 202 | OPERATOR pg_catalog.<=(double precision,double precision) 203 | OPERATOR pg_catalog.<=(timestamp with time zone,timestamp with time zone) 204 | OPERATOR pg_catalog.<=(oid,oid) 205 | OPERATOR pg_catalog.<=(character,character) 206 | OPERATOR pg_catalog.<=(time with time zone,time with time zone) 207 | OPERATOR pg_catalog.<=(time without time zone,time without time zone) 208 | OPERATOR pg_catalog.<=(timestamp without time zone,timestamp without time zone) 209 | OPERATOR pg_catalog.<=(pg_catalog.date,pg_catalog.date) 210 | OPERATOR pg_catalog.<=(boolean,boolean) 211 | OPERATOR pg_catalog.<=(bytea,bytea) 212 | OPERATOR pg_catalog.<=(name,name) 213 | OPERATOR pg_catalog.<=(real,real) 214 | OPERATOR pg_catalog.<=(bit,bit) 215 | OPERATOR pg_catalog.<=(anyenum,anyenum) 216 | OPERATOR pg_catalog.<>(bigint,bigint) 217 | OPERATOR pg_catalog.<>(integer,integer) 218 | OPERATOR pg_catalog.<>(text,text) 219 | OPERATOR pg_catalog.<>(smallint,integer) 220 | OPERATOR pg_catalog.<>(bigint,integer) 221 | OPERATOR pg_catalog.<>(numeric,numeric) 222 | OPERATOR pg_catalog.<>(smallint,smallint) 223 | OPERATOR pg_catalog.<>(double precision,double precision) 224 | OPERATOR pg_catalog.<>(timestamp with time zone,timestamp with time zone) 225 | OPERATOR pg_catalog.<>(oid,oid) 226 | OPERATOR pg_catalog.<>(character,character) 227 | OPERATOR pg_catalog.<>(time with time zone,time with time zone) 228 | OPERATOR pg_catalog.<>(time without time zone,time without time zone) 229 | OPERATOR pg_catalog.<>(timestamp without time zone,timestamp without time zone) 230 | OPERATOR pg_catalog.<>(boolean,boolean) 231 | OPERATOR pg_catalog.<>(bytea,bytea) 232 | OPERATOR pg_catalog.<>(name,name) 233 | OPERATOR pg_catalog.<>(real,real) 234 | OPERATOR pg_catalog.<>(pg_catalog.date,pg_catalog.date) 235 | OPERATOR pg_catalog.<>(bit,bit) 236 | OPERATOR pg_catalog.<>(anyenum,anyenum) 237 | OPERATOR pg_catalog.%(bigint,bigint) 238 | OPERATOR pg_catalog.%(smallint,smallint) 239 | OPERATOR pg_catalog.%(integer,integer) 240 | OPERATOR pg_catalog.%(numeric,numeric) 241 | OPERATOR pg_catalog.*(bigint,bigint) 242 | OPERATOR pg_catalog.*(smallint,smallint) 243 | OPERATOR pg_catalog.*(integer,integer) 244 | OPERATOR pg_catalog.*(numeric,numeric) 245 | OPERATOR pg_catalog.*(double precision,double precision) 246 | OPERATOR pg_catalog.*(bigint,integer) 247 | OPERATOR pg_catalog.*(real,real) 248 | OPERATOR pg_catalog.+(bigint,bigint) 249 | OPERATOR pg_catalog.+(smallint,smallint) 250 | OPERATOR pg_catalog.+(integer,integer) 251 | OPERATOR pg_catalog.+(numeric,numeric) 252 | OPERATOR pg_catalog.+(double precision,double precision) 253 | OPERATOR pg_catalog.+(real,real) 254 | OPERATOR pg_catalog.-(bigint,bigint) 255 | OPERATOR pg_catalog.-(smallint,smallint) 256 | OPERATOR pg_catalog.-(integer,integer) 257 | OPERATOR pg_catalog.-(numeric,numeric) 258 | OPERATOR pg_catalog.-(double precision,double precision) 259 | OPERATOR pg_catalog.-(timestamp with time zone,timestamp with time zone) 260 | OPERATOR pg_catalog.-(time without time zone,time without time zone) 261 | OPERATOR pg_catalog.-(timestamp without time zone,timestamp without time zone) 262 | OPERATOR pg_catalog.-(real,real) 263 | OPERATOR pg_catalog.-(pg_catalog.date,pg_catalog.date) 264 | OPERATOR pg_catalog.~~(text,text) 265 | OPERATOR pg_catalog.~~(character,text) 266 | OPERATOR pg_catalog./(bigint,bigint) 267 | OPERATOR pg_catalog./(smallint,smallint) 268 | OPERATOR pg_catalog./(integer,integer) 269 | OPERATOR pg_catalog./(numeric,numeric) 270 | OPERATOR pg_catalog./(double precision,double precision) 271 | OPERATOR pg_catalog./(real,real) 272 | -------------------------------------------------------------------------------- /expected/misc.out: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | -- Before running this file User must create database mysql_fdw_regress on 6 | -- MySQL with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 7 | -- and ran mysql_init.sh file to create tables. 8 | \c contrib_regression 9 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 10 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 11 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 12 | CREATE USER MAPPING FOR public SERVER mysql_svr 13 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 14 | CREATE SERVER mysql_svr1 FOREIGN DATA WRAPPER mysql_fdw 15 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 16 | CREATE USER MAPPING FOR public SERVER mysql_svr1 17 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 18 | -- Create foreign tables and insert data. 19 | CREATE FOREIGN TABLE fdw519_ft1(stu_id int, stu_name varchar(255), stu_dept int) 20 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student'); 21 | CREATE FOREIGN TABLE fdw519_ft2(c1 INTEGER, c2 VARCHAR(14), c3 VARCHAR(13)) 22 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl2'); 23 | CREATE FOREIGN TABLE fdw519_ft3 (c1 INTEGER, c2 VARCHAR(10), c3 CHAR(9), c4 BIGINT, c5 pg_catalog.Date, c6 DECIMAL, c7 INTEGER, c8 SMALLINT) 24 | SERVER mysql_svr1 OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl1'); 25 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 26 | INSERT INTO fdw519_ft2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 27 | INSERT INTO fdw519_ft2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 28 | INSERT INTO fdw519_ft3 VALUES (100, 'EMP1', 'ADMIN', 1300, '1980-12-17', 800.23, NULL, 20); 29 | INSERT INTO fdw519_ft3 VALUES (200, 'EMP2', 'SALESMAN', 600, '1981-02-20', 1600.00, 300, 30); 30 | -- Check truncatable option with invalid values. 31 | -- Since truncatable option is available since v14, this gives an error on v13 32 | -- and previous versions. 33 | ALTER SERVER mysql_svr OPTIONS (ADD truncatable 'abc'); 34 | ERROR: truncatable requires a Boolean value 35 | ALTER FOREIGN TABLE fdw519_ft1 OPTIONS (ADD truncatable 'abc'); 36 | ERROR: truncatable requires a Boolean value 37 | -- Default behavior, should truncate. 38 | TRUNCATE fdw519_ft1; 39 | SELECT * FROM fdw519_ft1 ORDER BY 1; 40 | stu_id | stu_name | stu_dept 41 | --------+----------+---------- 42 | (0 rows) 43 | 44 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 45 | -- Set truncatable to false 46 | -- Since truncatable option is available since v14, this gives an error on v13 47 | -- and previous versions. 48 | ALTER SERVER mysql_svr OPTIONS (ADD truncatable 'false'); 49 | -- Truncate the table. 50 | TRUNCATE fdw519_ft1; 51 | ERROR: foreign table "fdw519_ft1" does not allow truncates 52 | SELECT * FROM fdw519_ft1 ORDER BY 1; 53 | stu_id | stu_name | stu_dept 54 | --------+----------+---------- 55 | 1 | One | 101 56 | (1 row) 57 | 58 | -- Set truncatable to true 59 | -- Since truncatable option is available since v14, this gives an error on v13 60 | -- and previous versions. 61 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'true'); 62 | TRUNCATE fdw519_ft1; 63 | SELECT * FROM fdw519_ft1 ORDER BY 1; 64 | stu_id | stu_name | stu_dept 65 | --------+----------+---------- 66 | (0 rows) 67 | 68 | -- truncatable to true on Server but false on table level. 69 | -- Since truncatable option is available since v14, this gives an error on v13 70 | -- and previous versions. 71 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'false'); 72 | ALTER TABLE fdw519_ft2 OPTIONS (ADD truncatable 'true'); 73 | SELECT * FROM fdw519_ft2 ORDER BY 1; 74 | c1 | c2 | c3 75 | ----+----------------+---------- 76 | 10 | DEVELOPMENT | PUNE 77 | 20 | ADMINISTRATION | BANGLORE 78 | (2 rows) 79 | 80 | TRUNCATE fdw519_ft2; 81 | SELECT * FROM fdw519_ft2 ORDER BY 1; 82 | c1 | c2 | c3 83 | ----+----+---- 84 | (0 rows) 85 | 86 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 87 | INSERT INTO fdw519_ft2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 88 | INSERT INTO fdw519_ft2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 89 | -- truncatable to true on Server but false on one table and true for other 90 | -- table. 91 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'true'); 92 | ALTER TABLE fdw519_ft1 OPTIONS (ADD truncatable 'false'); 93 | ALTER TABLE fdw519_ft2 OPTIONS (SET truncatable 'true'); 94 | TRUNCATE fdw519_ft1, fdw519_ft2; 95 | ERROR: foreign table "fdw519_ft1" does not allow truncates 96 | SELECT * FROM fdw519_ft1 ORDER BY 1; 97 | stu_id | stu_name | stu_dept 98 | --------+----------+---------- 99 | 1 | One | 101 100 | (1 row) 101 | 102 | SELECT * FROM fdw519_ft2 ORDER BY 1; 103 | c1 | c2 | c3 104 | ----+----------------+---------- 105 | 10 | DEVELOPMENT | PUNE 106 | 20 | ADMINISTRATION | BANGLORE 107 | (2 rows) 108 | 109 | -- truncatable to false on Server but false on one table and true for other 110 | -- table. 111 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'false'); 112 | ALTER TABLE fdw519_ft1 OPTIONS (SET truncatable 'false'); 113 | ALTER TABLE fdw519_ft2 OPTIONS (SET truncatable 'true'); 114 | TRUNCATE fdw519_ft1, fdw519_ft2; 115 | ERROR: foreign table "fdw519_ft1" does not allow truncates 116 | SELECT * FROM fdw519_ft1 ORDER BY 1; 117 | stu_id | stu_name | stu_dept 118 | --------+----------+---------- 119 | 1 | One | 101 120 | (1 row) 121 | 122 | SELECT * FROM fdw519_ft2 ORDER BY 1; 123 | c1 | c2 | c3 124 | ----+----------------+---------- 125 | 10 | DEVELOPMENT | PUNE 126 | 20 | ADMINISTRATION | BANGLORE 127 | (2 rows) 128 | 129 | -- Truncate from different servers. 130 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'true'); 131 | ALTER SERVER mysql_svr1 OPTIONS (ADD truncatable 'true'); 132 | ALTER TABLE fdw519_ft1 OPTIONS (SET truncatable 'true'); 133 | TRUNCATE fdw519_ft1, fdw519_ft2, fdw519_ft3; 134 | SELECT * FROM fdw519_ft1 ORDER BY 1; 135 | stu_id | stu_name | stu_dept 136 | --------+----------+---------- 137 | (0 rows) 138 | 139 | SELECT * FROM fdw519_ft2 ORDER BY 1; 140 | c1 | c2 | c3 141 | ----+----+---- 142 | (0 rows) 143 | 144 | SELECT * FROM fdw519_ft3 ORDER BY 1; 145 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 146 | ----+----+----+----+----+----+----+---- 147 | (0 rows) 148 | 149 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 150 | SELECT * FROM fdw519_ft1 ORDER BY 1; 151 | stu_id | stu_name | stu_dept 152 | --------+----------+---------- 153 | 1 | One | 101 154 | (1 row) 155 | 156 | -- Truncate with CASCADE is not supported. 157 | TRUNCATE fdw519_ft1 CASCADE; 158 | ERROR: CASCADE option in TRUNCATE is not supported by this FDW 159 | SELECT * FROM fdw519_ft1 ORDER BY 1; 160 | stu_id | stu_name | stu_dept 161 | --------+----------+---------- 162 | 1 | One | 101 163 | (1 row) 164 | 165 | -- Default is RESTRICT, so it is allowed. 166 | TRUNCATE fdw519_ft1 RESTRICT; 167 | SELECT * FROM fdw519_ft1 ORDER BY 1; 168 | stu_id | stu_name | stu_dept 169 | --------+----------+---------- 170 | (0 rows) 171 | 172 | -- Should throw an error if primary key is referenced by foreign key. 173 | CREATE FOREIGN TABLE fdw519_ft4(stu_id varchar(10), stu_name varchar(255), stu_dept int) 174 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student1'); 175 | CREATE FOREIGN TABLE fdw519_ft5(dept_id int, stu_id varchar(10)) 176 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'dept'); 177 | TRUNCATE fdw519_ft4; 178 | ERROR: failed to execute the MySQL query: 179 | Cannot truncate a table referenced in a foreign key constraint (`mysql_fdw_regress1`.`dept`, CONSTRAINT `dept_ibfk_1`) 180 | -- FDW-520: Support generated columns in IMPORT FOREIGN SCHEMA command. 181 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520) 182 | FROM SERVER mysql_svr INTO public OPTIONS (import_generated 'true'); 183 | \d fdw520 184 | Foreign table "public.fdw520" 185 | Column | Type | Collation | Nullable | Default | FDW options 186 | ---------+---------+-----------+----------+----------------------------------------------+------------- 187 | c1 | integer | | not null | | 188 | c `"" 2 | integer | | | | 189 | c3 | integer | | | generated always as ("c `"""" 2" * 2) stored | 190 | c4 | integer | | not null | generated always as ("c `"""" 2" * 4) stored | 191 | Server: mysql_svr 192 | FDW options: (dbname 'mysql_fdw_regress', table_name 'fdw520') 193 | 194 | -- Generated column refers to another generated column, should throw an error: 195 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520_1) 196 | FROM SERVER mysql_svr INTO public OPTIONS (import_generated 'true'); 197 | ERROR: cannot use generated column "c3" in column generation expression 198 | LINE 5: c4 int GENERATED ALWAYS AS ("c3" * 4) STORED NOT NULL 199 | ^ 200 | DETAIL: A generated column cannot reference another generated column. 201 | QUERY: CREATE FOREIGN TABLE fdw520_1 ( 202 | c1 int NOT NULL, 203 | c2 int, 204 | c3 int GENERATED ALWAYS AS ("c2" * 2) STORED, 205 | c4 int GENERATED ALWAYS AS ("c3" * 4) STORED NOT NULL 206 | ) SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'fdw520_1'); 207 | 208 | CONTEXT: importing foreign table "fdw520_1" 209 | -- import_generated as false. 210 | DROP FOREIGN TABLE fdw520; 211 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520) 212 | FROM SERVER mysql_svr INTO public OPTIONS (import_generated 'false'); 213 | \d fdw520 214 | Foreign table "public.fdw520" 215 | Column | Type | Collation | Nullable | Default | FDW options 216 | ---------+---------+-----------+----------+---------+------------- 217 | c1 | integer | | not null | | 218 | c `"" 2 | integer | | | | 219 | c3 | integer | | | | 220 | c4 | integer | | not null | | 221 | Server: mysql_svr 222 | FDW options: (dbname 'mysql_fdw_regress', table_name 'fdw520') 223 | 224 | -- Without import_generated option, default is true. 225 | DROP FOREIGN TABLE fdw520; 226 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520) 227 | FROM SERVER mysql_svr INTO public; 228 | \d fdw520 229 | Foreign table "public.fdw520" 230 | Column | Type | Collation | Nullable | Default | FDW options 231 | ---------+---------+-----------+----------+----------------------------------------------+------------- 232 | c1 | integer | | not null | | 233 | c `"" 2 | integer | | | | 234 | c3 | integer | | | generated always as ("c `"""" 2" * 2) stored | 235 | c4 | integer | | not null | generated always as ("c `"""" 2" * 4) stored | 236 | Server: mysql_svr 237 | FDW options: (dbname 'mysql_fdw_regress', table_name 'fdw520') 238 | 239 | -- FDW-521: Insert and update operations on table having generated columns. 240 | INSERT INTO fdw520(c1, "c `"""" 2") VALUES(1, 2); 241 | INSERT INTO fdw520(c1, "c `"""" 2", c3, c4) VALUES(2, 4, DEFAULT, DEFAULT); 242 | -- Should fail. 243 | INSERT INTO fdw520 VALUES(1, 2, 3, 4); 244 | ERROR: cannot insert a non-DEFAULT value into column "c3" 245 | DETAIL: Column "c3" is a generated column. 246 | SELECT * FROM fdw520 ORDER BY 1; 247 | c1 | c `"" 2 | c3 | c4 248 | ----+---------+----+---- 249 | 1 | 2 | 4 | 8 250 | 2 | 4 | 8 | 16 251 | (2 rows) 252 | 253 | UPDATE fdw520 SET "c `"""" 2" = 20 WHERE c1 = 2; 254 | SELECT * FROM fdw520 ORDER BY 1; 255 | c1 | c `"" 2 | c3 | c4 256 | ----+---------+----+---- 257 | 1 | 2 | 4 | 8 258 | 2 | 20 | 40 | 80 259 | (2 rows) 260 | 261 | -- Should fail. 262 | UPDATE fdw520 SET c4 = 20 WHERE c1 = 2; 263 | ERROR: column "c4" can only be updated to DEFAULT 264 | DETAIL: Column "c4" is a generated column. 265 | UPDATE fdw520 SET c3 = 20 WHERE c1 = 2; 266 | ERROR: column "c3" can only be updated to DEFAULT 267 | DETAIL: Column "c3" is a generated column. 268 | -- Cleanup 269 | DELETE FROM fdw519_ft1; 270 | DELETE FROM fdw519_ft2; 271 | DELETE FROM fdw519_ft3; 272 | DELETE FROM fdw520; 273 | DROP FOREIGN TABLE fdw519_ft1; 274 | DROP FOREIGN TABLE fdw519_ft2; 275 | DROP FOREIGN TABLE fdw519_ft3; 276 | DROP FOREIGN TABLE fdw519_ft4; 277 | DROP FOREIGN TABLE fdw519_ft5; 278 | DROP FOREIGN TABLE fdw520; 279 | DROP USER MAPPING FOR public SERVER mysql_svr; 280 | DROP SERVER mysql_svr; 281 | DROP USER MAPPING FOR public SERVER mysql_svr1; 282 | DROP SERVER mysql_svr1; 283 | DROP EXTENSION mysql_fdw; 284 | -------------------------------------------------------------------------------- /expected/dml.out: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | -- Before running this file User must create database mysql_fdw_regress on 6 | -- MySQL with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 7 | -- and ran mysql_init.sh file to create tables. 8 | \c contrib_regression 9 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 10 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 11 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 12 | CREATE USER MAPPING FOR public SERVER mysql_svr 13 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 14 | -- Create foreign tables 15 | CREATE FOREIGN TABLE f_mysql_test(a int, b int) 16 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test'); 17 | CREATE FOREIGN TABLE fdw126_ft1(stu_id int, stu_name varchar(255), stu_dept int) 18 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student'); 19 | CREATE FOREIGN TABLE fdw126_ft2(stu_id int, stu_name varchar(255)) 20 | SERVER mysql_svr OPTIONS (table_name 'student'); 21 | CREATE FOREIGN TABLE fdw126_ft3(a int, b varchar(255)) 22 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'numbers'); 23 | CREATE FOREIGN TABLE fdw126_ft4(a int, b varchar(255)) 24 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'nosuchtable'); 25 | CREATE FOREIGN TABLE fdw126_ft5(a int, b varchar(255)) 26 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress2', table_name 'numbers'); 27 | CREATE FOREIGN TABLE fdw126_ft6(stu_id int, stu_name varchar(255)) 28 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'mysql_fdw_regress1.student'); 29 | CREATE FOREIGN TABLE f_empdata(emp_id int, emp_dat bytea) 30 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'empdata'); 31 | CREATE FOREIGN TABLE fdw193_ft1(stu_id varchar(10), stu_name varchar(255), stu_dept int) 32 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student1'); 33 | -- Operation on blob data. 34 | INSERT INTO f_empdata VALUES (1, decode ('01234567', 'hex')); 35 | INSERT INTO f_empdata VALUES (2, 'abc'); 36 | SELECT count(*) FROM f_empdata ORDER BY 1; 37 | count 38 | ------- 39 | 2 40 | (1 row) 41 | 42 | SELECT emp_id, emp_dat FROM f_empdata ORDER BY 1; 43 | emp_id | emp_dat 44 | --------+------------ 45 | 1 | \x01234567 46 | 2 | \x616263 47 | (2 rows) 48 | 49 | UPDATE f_empdata SET emp_dat = decode ('0123', 'hex') WHERE emp_id = 1; 50 | SELECT emp_id, emp_dat FROM f_empdata ORDER BY 1; 51 | emp_id | emp_dat 52 | --------+---------- 53 | 1 | \x0123 54 | 2 | \x616263 55 | (2 rows) 56 | 57 | -- FDW-126: Insert/update/delete statement failing in mysql_fdw by picking 58 | -- wrong database name. 59 | -- Verify the INSERT/UPDATE/DELETE operations on another foreign table which 60 | -- resides in the another database in MySQL. The previous commands performs 61 | -- the operation on foreign table created for tables in mysql_fdw_regress 62 | -- MySQL database. Below operations will be performed for foreign table 63 | -- created for table in mysql_fdw_regress1 MySQL database. 64 | INSERT INTO fdw126_ft1 VALUES(1, 'One', 101); 65 | UPDATE fdw126_ft1 SET stu_name = 'one' WHERE stu_id = 1; 66 | DELETE FROM fdw126_ft1 WHERE stu_id = 1; 67 | -- Select on f_mysql_test foreign table which is created for mysql_test table 68 | -- from mysql_fdw_regress MySQL database. This call is just to cross verify if 69 | -- everything is working correctly. 70 | SELECT a, b FROM f_mysql_test ORDER BY 1, 2; 71 | a | b 72 | ---+--- 73 | 1 | 1 74 | (1 row) 75 | 76 | -- Insert into fdw126_ft2 table which does not have dbname specified while 77 | -- creating the foreign table, so it will consider the schema name of foreign 78 | -- table as database name and try to connect/lookup into that database. Will 79 | -- throw an error. The error message is different on old mysql and mariadb 80 | -- servers so give the generic message. 81 | DO 82 | $$ 83 | BEGIN 84 | INSERT INTO fdw126_ft2 VALUES(2, 'Two'); 85 | EXCEPTION WHEN others THEN 86 | IF SQLERRM LIKE '%SELECT command denied to user ''%''@''%'' for table ''student''' THEN 87 | RAISE NOTICE E'failed to execute the MySQL query: \nUnknown database ''public'''; 88 | ELSE 89 | RAISE NOTICE '%', SQLERRM; 90 | END IF; 91 | END; 92 | $$ 93 | LANGUAGE plpgsql; 94 | NOTICE: failed to execute the MySQL query: 95 | Unknown database 'public' 96 | -- Check with the same table name from different database. fdw126_ft3 is 97 | -- pointing to the mysql_fdw_regress1.numbers and not mysql_fdw_regress.numbers 98 | -- table. INSERT/UPDATE/DELETE should be failing. SELECT will return no rows. 99 | INSERT INTO fdw126_ft3 VALUES(1, 'One'); 100 | ERROR: first column of remote table must be unique for INSERT/UPDATE/DELETE operation 101 | SELECT a, b FROM fdw126_ft3 ORDER BY 1, 2 LIMIT 1; 102 | a | b 103 | ---+--- 104 | (0 rows) 105 | 106 | UPDATE fdw126_ft3 SET b = 'one' WHERE a = 1; 107 | ERROR: first column of remote table must be unique for INSERT/UPDATE/DELETE operation 108 | DELETE FROM fdw126_ft3 WHERE a = 1; 109 | ERROR: first column of remote table must be unique for INSERT/UPDATE/DELETE operation 110 | -- Check when table_name is given in database.table form in foreign table 111 | -- should error out as table does not exists. 112 | INSERT INTO fdw126_ft6 VALUES(1, 'One'); 113 | ERROR: failed to execute the MySQL query: 114 | Table 'mysql_fdw_regress1.mysql_fdw_regress1.student' doesn't exist 115 | -- Perform the ANALYZE on the foreign table which is not present on the remote 116 | -- side. Should not crash. 117 | -- The database is present but not the target table. 118 | ANALYZE fdw126_ft4; 119 | ERROR: relation mysql_fdw_regress1.nosuchtable does not exist 120 | -- The database itself is not present. 121 | ANALYZE fdw126_ft5; 122 | ERROR: relation mysql_fdw_regress2.numbers does not exist 123 | -- Some other variant of analyze and vacuum. 124 | -- when table exists, should give skip-warning 125 | VACUUM f_empdata; 126 | WARNING: skipping "f_empdata" --- cannot vacuum non-tables or special system tables 127 | VACUUM FULL f_empdata; 128 | WARNING: skipping "f_empdata" --- cannot vacuum non-tables or special system tables 129 | VACUUM FREEZE f_empdata; 130 | WARNING: skipping "f_empdata" --- cannot vacuum non-tables or special system tables 131 | ANALYZE f_empdata; 132 | WARNING: skipping "f_empdata" --- cannot analyze this foreign table 133 | ANALYZE f_empdata(emp_id); 134 | WARNING: skipping "f_empdata" --- cannot analyze this foreign table 135 | VACUUM ANALYZE f_empdata; 136 | WARNING: skipping "f_empdata" --- cannot vacuum non-tables or special system tables 137 | -- Verify the before update trigger which modifies the column value which is not 138 | -- part of update statement. 139 | CREATE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 140 | BEGIN 141 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 142 | RETURN NEW; 143 | END 144 | $$ language plpgsql; 145 | CREATE TRIGGER before_row_update_trig 146 | BEFORE UPDATE ON fdw126_ft1 147 | FOR EACH ROW EXECUTE PROCEDURE before_row_update_func(); 148 | INSERT INTO fdw126_ft1 VALUES(1, 'One', 101); 149 | UPDATE fdw126_ft1 SET stu_dept = 201 WHERE stu_id = 1; 150 | SELECT * FROM fdw126_ft1 ORDER BY stu_id; 151 | stu_id | stu_name | stu_dept 152 | --------+----------------------+---------- 153 | 1 | One trigger updated! | 201 154 | (1 row) 155 | 156 | -- Throw an error when target list has row identifier column. 157 | UPDATE fdw126_ft1 SET stu_dept = 201, stu_id = 10 WHERE stu_id = 1; 158 | ERROR: row identifier column update is not supported 159 | -- Throw an error when before row update trigger modify the row identifier 160 | -- column (int column) value. 161 | CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 162 | BEGIN 163 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 164 | NEW.stu_id = 20; 165 | RETURN NEW; 166 | END 167 | $$ language plpgsql; 168 | UPDATE fdw126_ft1 SET stu_dept = 301 WHERE stu_id = 1; 169 | ERROR: row identifier column update is not supported 170 | -- Verify the before update trigger which modifies the column value which is 171 | -- not part of update statement. 172 | CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 173 | BEGIN 174 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 175 | RETURN NEW; 176 | END 177 | $$ language plpgsql; 178 | CREATE TRIGGER before_row_update_trig1 179 | BEFORE UPDATE ON fdw193_ft1 180 | FOR EACH ROW EXECUTE PROCEDURE before_row_update_func(); 181 | INSERT INTO fdw193_ft1 VALUES('aa', 'One', 101); 182 | UPDATE fdw193_ft1 SET stu_dept = 201 WHERE stu_id = 'aa'; 183 | SELECT * FROM fdw193_ft1 ORDER BY stu_id; 184 | stu_id | stu_name | stu_dept 185 | --------+----------------------+---------- 186 | aa | One trigger updated! | 201 187 | (1 row) 188 | 189 | -- Throw an error when before row update trigger modify the row identifier 190 | -- column (varchar column) value. 191 | CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 192 | BEGIN 193 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 194 | NEW.stu_id = 'bb'; 195 | RETURN NEW; 196 | END 197 | $$ language plpgsql; 198 | UPDATE fdw193_ft1 SET stu_dept = 301 WHERE stu_id = 'aa'; 199 | ERROR: row identifier column update is not supported 200 | -- Verify the NULL assignment scenario. 201 | CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$ 202 | BEGIN 203 | NEW.stu_name := NEW.stu_name || ' trigger updated!'; 204 | NEW.stu_id = NULL; 205 | RETURN NEW; 206 | END 207 | $$ language plpgsql; 208 | UPDATE fdw193_ft1 SET stu_dept = 401 WHERE stu_id = 'aa'; 209 | ERROR: row identifier column update is not supported 210 | -- FDW-224 Fix COPY FROM and foreign partition routing result in server crash 211 | -- Should fail as foreign table direct copy not supported 212 | COPY f_mysql_test TO stdout; 213 | ERROR: cannot copy from foreign table "f_mysql_test" 214 | HINT: Try the COPY (SELECT ...) TO variant. 215 | COPY f_mysql_test (a) TO stdout; 216 | ERROR: cannot copy from foreign table "f_mysql_test" 217 | HINT: Try the COPY (SELECT ...) TO variant. 218 | -- Should pass 219 | COPY (SELECT * FROM f_mysql_test) TO stdout; 220 | 1 1 221 | COPY (SELECT a FROM f_mysql_test) TO '/tmp/copy_test.txt' delimiter ','; 222 | -- Should give error message as copy from with foreign table not supported 223 | DO 224 | $$ 225 | BEGIN 226 | COPY f_mysql_test(a) FROM '/tmp/copy_test.txt' delimiter ','; 227 | EXCEPTION WHEN others THEN 228 | IF SQLERRM = 'COPY and foreign partition routing not supported in mysql_fdw' OR 229 | SQLERRM = 'cannot copy to foreign table "f_mysql_test"' THEN 230 | RAISE NOTICE 'ERROR: COPY and foreign partition routing not supported in mysql_fdw'; 231 | ELSE 232 | RAISE NOTICE '%', SQLERRM; 233 | END IF; 234 | END; 235 | $$ 236 | LANGUAGE plpgsql; 237 | NOTICE: ERROR: COPY and foreign partition routing not supported in mysql_fdw 238 | -- FDW-518: Should honor ON CONFLICT DO NOTHING clause. 239 | SELECT * FROM f_mysql_test ORDER BY 1; 240 | a | b 241 | ---+--- 242 | 1 | 1 243 | (1 row) 244 | 245 | -- Should not throw an error while inserting duplicate value as we are using 246 | -- ON CONFLICT DO NOTHING clause. 247 | INSERT INTO f_mysql_test VALUES(1,1) ON CONFLICT DO NOTHING; 248 | SELECT * FROM f_mysql_test ORDER BY 1; 249 | a | b 250 | ---+--- 251 | 1 | 1 252 | (1 row) 253 | 254 | -- Should throw an error 255 | INSERT INTO f_mysql_test VALUES(1,1) ON CONFLICT (a, b) DO NOTHING; 256 | ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification 257 | INSERT INTO f_mysql_test VALUES(1,1) ON CONFLICT DO UPDATE SET b = 10; 258 | ERROR: ON CONFLICT DO UPDATE requires inference specification or constraint name 259 | LINE 1: INSERT INTO f_mysql_test VALUES(1,1) ON CONFLICT DO UPDATE S... 260 | ^ 261 | HINT: For example, ON CONFLICT (column_name). 262 | INSERT INTO f_mysql_test VALUES(1,1) ON CONFLICT (a) DO UPDATE SET b = 10; 263 | ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification 264 | -- FDW-601: database and table name should be quoted correctly in case of 265 | -- INSERT/UPDATE/DELETE. 266 | CREATE FOREIGN TABLE fdw601(a int, b int) 267 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'fdw-601'); 268 | INSERT INTO fdw601 VALUES(1,1), (2,2); 269 | UPDATE fdw601 SET b = 3 WHERE b = 2; 270 | DELETE FROM fdw601 WHERE b = 1; 271 | SELECT * FROM fdw601 ORDER BY 1; 272 | a | b 273 | ---+--- 274 | 2 | 3 275 | (1 row) 276 | 277 | DELETE FROM fdw601; 278 | -- Cleanup 279 | DELETE FROM fdw126_ft1; 280 | DELETE FROM f_empdata; 281 | DELETE FROM fdw193_ft1; 282 | DROP FOREIGN TABLE f_mysql_test; 283 | DROP FOREIGN TABLE fdw126_ft1; 284 | DROP FOREIGN TABLE fdw126_ft2; 285 | DROP FOREIGN TABLE fdw126_ft3; 286 | DROP FOREIGN TABLE fdw126_ft4; 287 | DROP FOREIGN TABLE fdw126_ft5; 288 | DROP FOREIGN TABLE fdw126_ft6; 289 | DROP FOREIGN TABLE f_empdata; 290 | DROP FOREIGN TABLE fdw193_ft1; 291 | DROP FOREIGN TABLE fdw601; 292 | DROP FUNCTION before_row_update_func(); 293 | DROP USER MAPPING FOR public SERVER mysql_svr; 294 | DROP SERVER mysql_svr; 295 | DROP EXTENSION mysql_fdw; 296 | -------------------------------------------------------------------------------- /expected/misc_1.out: -------------------------------------------------------------------------------- 1 | \set MYSQL_HOST `echo \'"$MYSQL_HOST"\'` 2 | \set MYSQL_PORT `echo \'"$MYSQL_PORT"\'` 3 | \set MYSQL_USER_NAME `echo \'"$MYSQL_USER_NAME"\'` 4 | \set MYSQL_PASS `echo \'"$MYSQL_PWD"\'` 5 | -- Before running this file User must create database mysql_fdw_regress on 6 | -- MySQL with all permission for MYSQL_USER_NAME user with MYSQL_PWD password 7 | -- and ran mysql_init.sh file to create tables. 8 | \c contrib_regression 9 | CREATE EXTENSION IF NOT EXISTS mysql_fdw; 10 | CREATE SERVER mysql_svr FOREIGN DATA WRAPPER mysql_fdw 11 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 12 | CREATE USER MAPPING FOR public SERVER mysql_svr 13 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 14 | CREATE SERVER mysql_svr1 FOREIGN DATA WRAPPER mysql_fdw 15 | OPTIONS (host :MYSQL_HOST, port :MYSQL_PORT); 16 | CREATE USER MAPPING FOR public SERVER mysql_svr1 17 | OPTIONS (username :MYSQL_USER_NAME, password :MYSQL_PASS); 18 | -- Create foreign tables and insert data. 19 | CREATE FOREIGN TABLE fdw519_ft1(stu_id int, stu_name varchar(255), stu_dept int) 20 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student'); 21 | CREATE FOREIGN TABLE fdw519_ft2(c1 INTEGER, c2 VARCHAR(14), c3 VARCHAR(13)) 22 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl2'); 23 | CREATE FOREIGN TABLE fdw519_ft3 (c1 INTEGER, c2 VARCHAR(10), c3 CHAR(9), c4 BIGINT, c5 pg_catalog.Date, c6 DECIMAL, c7 INTEGER, c8 SMALLINT) 24 | SERVER mysql_svr1 OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl1'); 25 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 26 | INSERT INTO fdw519_ft2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 27 | INSERT INTO fdw519_ft2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 28 | INSERT INTO fdw519_ft3 VALUES (100, 'EMP1', 'ADMIN', 1300, '1980-12-17', 800.23, NULL, 20); 29 | INSERT INTO fdw519_ft3 VALUES (200, 'EMP2', 'SALESMAN', 600, '1981-02-20', 1600.00, 300, 30); 30 | -- Check truncatable option with invalid values. 31 | -- Since truncatable option is available since v14, this gives an error on v13 32 | -- and previous versions. 33 | ALTER SERVER mysql_svr OPTIONS (ADD truncatable 'abc'); 34 | ERROR: invalid option "truncatable" 35 | HINT: Valid options in this context are: host, port, init_command, secure_auth, use_remote_estimate, fetch_size, reconnect, character_set, mysql_default_file, sql_mode, ssl_key, ssl_cert, ssl_ca, ssl_capath, ssl_cipher 36 | ALTER FOREIGN TABLE fdw519_ft1 OPTIONS (ADD truncatable 'abc'); 37 | ERROR: invalid option "truncatable" 38 | HINT: Valid options in this context are: dbname, table_name, max_blob_size, fetch_size 39 | -- Default behavior, should truncate. 40 | TRUNCATE fdw519_ft1; 41 | ERROR: "fdw519_ft1" is not a table 42 | SELECT * FROM fdw519_ft1 ORDER BY 1; 43 | stu_id | stu_name | stu_dept 44 | --------+----------+---------- 45 | 1 | One | 101 46 | (1 row) 47 | 48 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 49 | ERROR: failed to execute the MySQL query: 50 | Duplicate entry '1' for key 'student.PRIMARY' 51 | -- Set truncatable to false 52 | -- Since truncatable option is available since v14, this gives an error on v13 53 | -- and previous versions. 54 | ALTER SERVER mysql_svr OPTIONS (ADD truncatable 'false'); 55 | ERROR: invalid option "truncatable" 56 | HINT: Valid options in this context are: host, port, init_command, secure_auth, use_remote_estimate, fetch_size, reconnect, character_set, mysql_default_file, sql_mode, ssl_key, ssl_cert, ssl_ca, ssl_capath, ssl_cipher 57 | -- Truncate the table. 58 | TRUNCATE fdw519_ft1; 59 | ERROR: "fdw519_ft1" is not a table 60 | SELECT * FROM fdw519_ft1 ORDER BY 1; 61 | stu_id | stu_name | stu_dept 62 | --------+----------+---------- 63 | 1 | One | 101 64 | (1 row) 65 | 66 | -- Set truncatable to true 67 | -- Since truncatable option is available since v14, this gives an error on v13 68 | -- and previous versions. 69 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'true'); 70 | ERROR: option "truncatable" not found 71 | TRUNCATE fdw519_ft1; 72 | ERROR: "fdw519_ft1" is not a table 73 | SELECT * FROM fdw519_ft1 ORDER BY 1; 74 | stu_id | stu_name | stu_dept 75 | --------+----------+---------- 76 | 1 | One | 101 77 | (1 row) 78 | 79 | -- truncatable to true on Server but false on table level. 80 | -- Since truncatable option is available since v14, this gives an error on v13 81 | -- and previous versions. 82 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'false'); 83 | ERROR: option "truncatable" not found 84 | ALTER TABLE fdw519_ft2 OPTIONS (ADD truncatable 'true'); 85 | ERROR: invalid option "truncatable" 86 | HINT: Valid options in this context are: dbname, table_name, max_blob_size, fetch_size 87 | SELECT * FROM fdw519_ft2 ORDER BY 1; 88 | c1 | c2 | c3 89 | ----+----------------+---------- 90 | 10 | DEVELOPMENT | PUNE 91 | 20 | ADMINISTRATION | BANGLORE 92 | (2 rows) 93 | 94 | TRUNCATE fdw519_ft2; 95 | ERROR: "fdw519_ft2" is not a table 96 | SELECT * FROM fdw519_ft2 ORDER BY 1; 97 | c1 | c2 | c3 98 | ----+----------------+---------- 99 | 10 | DEVELOPMENT | PUNE 100 | 20 | ADMINISTRATION | BANGLORE 101 | (2 rows) 102 | 103 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 104 | ERROR: failed to execute the MySQL query: 105 | Duplicate entry '1' for key 'student.PRIMARY' 106 | INSERT INTO fdw519_ft2 VALUES(10, 'DEVELOPMENT', 'PUNE'); 107 | ERROR: failed to execute the MySQL query: 108 | Duplicate entry '10' for key 'test_tbl2.PRIMARY' 109 | INSERT INTO fdw519_ft2 VALUES(20, 'ADMINISTRATION', 'BANGLORE'); 110 | ERROR: failed to execute the MySQL query: 111 | Duplicate entry '20' for key 'test_tbl2.PRIMARY' 112 | -- truncatable to true on Server but false on one table and true for other 113 | -- table. 114 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'true'); 115 | ERROR: option "truncatable" not found 116 | ALTER TABLE fdw519_ft1 OPTIONS (ADD truncatable 'false'); 117 | ERROR: invalid option "truncatable" 118 | HINT: Valid options in this context are: dbname, table_name, max_blob_size, fetch_size 119 | ALTER TABLE fdw519_ft2 OPTIONS (SET truncatable 'true'); 120 | ERROR: option "truncatable" not found 121 | TRUNCATE fdw519_ft1, fdw519_ft2; 122 | ERROR: "fdw519_ft1" is not a table 123 | SELECT * FROM fdw519_ft1 ORDER BY 1; 124 | stu_id | stu_name | stu_dept 125 | --------+----------+---------- 126 | 1 | One | 101 127 | (1 row) 128 | 129 | SELECT * FROM fdw519_ft2 ORDER BY 1; 130 | c1 | c2 | c3 131 | ----+----------------+---------- 132 | 10 | DEVELOPMENT | PUNE 133 | 20 | ADMINISTRATION | BANGLORE 134 | (2 rows) 135 | 136 | -- truncatable to false on Server but false on one table and true for other 137 | -- table. 138 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'false'); 139 | ERROR: option "truncatable" not found 140 | ALTER TABLE fdw519_ft1 OPTIONS (SET truncatable 'false'); 141 | ERROR: option "truncatable" not found 142 | ALTER TABLE fdw519_ft2 OPTIONS (SET truncatable 'true'); 143 | ERROR: option "truncatable" not found 144 | TRUNCATE fdw519_ft1, fdw519_ft2; 145 | ERROR: "fdw519_ft1" is not a table 146 | SELECT * FROM fdw519_ft1 ORDER BY 1; 147 | stu_id | stu_name | stu_dept 148 | --------+----------+---------- 149 | 1 | One | 101 150 | (1 row) 151 | 152 | SELECT * FROM fdw519_ft2 ORDER BY 1; 153 | c1 | c2 | c3 154 | ----+----------------+---------- 155 | 10 | DEVELOPMENT | PUNE 156 | 20 | ADMINISTRATION | BANGLORE 157 | (2 rows) 158 | 159 | -- Truncate from different servers. 160 | ALTER SERVER mysql_svr OPTIONS (SET truncatable 'true'); 161 | ERROR: option "truncatable" not found 162 | ALTER SERVER mysql_svr1 OPTIONS (ADD truncatable 'true'); 163 | ERROR: invalid option "truncatable" 164 | HINT: Valid options in this context are: host, port, init_command, secure_auth, use_remote_estimate, fetch_size, reconnect, character_set, mysql_default_file, sql_mode, ssl_key, ssl_cert, ssl_ca, ssl_capath, ssl_cipher 165 | ALTER TABLE fdw519_ft1 OPTIONS (SET truncatable 'true'); 166 | ERROR: option "truncatable" not found 167 | TRUNCATE fdw519_ft1, fdw519_ft2, fdw519_ft3; 168 | ERROR: "fdw519_ft1" is not a table 169 | SELECT * FROM fdw519_ft1 ORDER BY 1; 170 | stu_id | stu_name | stu_dept 171 | --------+----------+---------- 172 | 1 | One | 101 173 | (1 row) 174 | 175 | SELECT * FROM fdw519_ft2 ORDER BY 1; 176 | c1 | c2 | c3 177 | ----+----------------+---------- 178 | 10 | DEVELOPMENT | PUNE 179 | 20 | ADMINISTRATION | BANGLORE 180 | (2 rows) 181 | 182 | SELECT * FROM fdw519_ft3 ORDER BY 1; 183 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 184 | -----+------+-----------+------+------------+------------+-----+---- 185 | 100 | EMP1 | ADMIN | 1300 | 12-17-1980 | 800.23000 | | 20 186 | 200 | EMP2 | SALESMAN | 600 | 02-20-1981 | 1600.00000 | 300 | 30 187 | (2 rows) 188 | 189 | INSERT INTO fdw519_ft1 VALUES(1, 'One', 101); 190 | ERROR: failed to execute the MySQL query: 191 | Duplicate entry '1' for key 'student.PRIMARY' 192 | SELECT * FROM fdw519_ft1 ORDER BY 1; 193 | stu_id | stu_name | stu_dept 194 | --------+----------+---------- 195 | 1 | One | 101 196 | (1 row) 197 | 198 | -- Truncate with CASCADE is not supported. 199 | TRUNCATE fdw519_ft1 CASCADE; 200 | ERROR: "fdw519_ft1" is not a table 201 | SELECT * FROM fdw519_ft1 ORDER BY 1; 202 | stu_id | stu_name | stu_dept 203 | --------+----------+---------- 204 | 1 | One | 101 205 | (1 row) 206 | 207 | -- Default is RESTRICT, so it is allowed. 208 | TRUNCATE fdw519_ft1 RESTRICT; 209 | ERROR: "fdw519_ft1" is not a table 210 | SELECT * FROM fdw519_ft1 ORDER BY 1; 211 | stu_id | stu_name | stu_dept 212 | --------+----------+---------- 213 | 1 | One | 101 214 | (1 row) 215 | 216 | -- Should throw an error if primary key is referenced by foreign key. 217 | CREATE FOREIGN TABLE fdw519_ft4(stu_id varchar(10), stu_name varchar(255), stu_dept int) 218 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student1'); 219 | CREATE FOREIGN TABLE fdw519_ft5(dept_id int, stu_id varchar(10)) 220 | SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'dept'); 221 | TRUNCATE fdw519_ft4; 222 | ERROR: "fdw519_ft4" is not a table 223 | -- FDW-520: Support generated columns in IMPORT FOREIGN SCHEMA command. 224 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520) 225 | FROM SERVER mysql_svr INTO public OPTIONS (import_generated 'true'); 226 | ERROR: invalid option "import_generated" 227 | \d fdw520 228 | -- Generated column refers to another generated column, should throw an error: 229 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520_1) 230 | FROM SERVER mysql_svr INTO public OPTIONS (import_generated 'true'); 231 | ERROR: invalid option "import_generated" 232 | -- import_generated as false. 233 | DROP FOREIGN TABLE fdw520; 234 | ERROR: foreign table "fdw520" does not exist 235 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520) 236 | FROM SERVER mysql_svr INTO public OPTIONS (import_generated 'false'); 237 | ERROR: invalid option "import_generated" 238 | \d fdw520 239 | -- Without import_generated option, default is true. 240 | DROP FOREIGN TABLE fdw520; 241 | ERROR: foreign table "fdw520" does not exist 242 | IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (fdw520) 243 | FROM SERVER mysql_svr INTO public; 244 | \d fdw520 245 | Foreign table "public.fdw520" 246 | Column | Type | Collation | Nullable | Default | FDW options 247 | ---------+---------+-----------+----------+---------+------------- 248 | c1 | integer | | not null | | 249 | c `"" 2 | integer | | | | 250 | c3 | integer | | | | 251 | c4 | integer | | not null | | 252 | Server: mysql_svr 253 | FDW options: (dbname 'mysql_fdw_regress', table_name 'fdw520') 254 | 255 | -- FDW-521: Insert and update operations on table having generated columns. 256 | INSERT INTO fdw520(c1, "c `"""" 2") VALUES(1, 2); 257 | ERROR: failed to prepare the MySQL query: 258 | The value specified for generated column 'c3' in table 'fdw520' is not allowed. 259 | INSERT INTO fdw520(c1, "c `"""" 2", c3, c4) VALUES(2, 4, DEFAULT, DEFAULT); 260 | ERROR: failed to prepare the MySQL query: 261 | The value specified for generated column 'c3' in table 'fdw520' is not allowed. 262 | -- Should fail. 263 | INSERT INTO fdw520 VALUES(1, 2, 3, 4); 264 | ERROR: failed to prepare the MySQL query: 265 | The value specified for generated column 'c3' in table 'fdw520' is not allowed. 266 | SELECT * FROM fdw520 ORDER BY 1; 267 | c1 | c `"" 2 | c3 | c4 268 | ----+---------+----+---- 269 | (0 rows) 270 | 271 | UPDATE fdw520 SET "c `"""" 2" = 20 WHERE c1 = 2; 272 | SELECT * FROM fdw520 ORDER BY 1; 273 | c1 | c `"" 2 | c3 | c4 274 | ----+---------+----+---- 275 | (0 rows) 276 | 277 | -- Should fail. 278 | UPDATE fdw520 SET c4 = 20 WHERE c1 = 2; 279 | ERROR: failed to prepare the MySQL query: 280 | The value specified for generated column 'c4' in table 'fdw520' is not allowed. 281 | UPDATE fdw520 SET c3 = 20 WHERE c1 = 2; 282 | ERROR: failed to prepare the MySQL query: 283 | The value specified for generated column 'c3' in table 'fdw520' is not allowed. 284 | -- Cleanup 285 | DELETE FROM fdw519_ft1; 286 | DELETE FROM fdw519_ft2; 287 | DELETE FROM fdw519_ft3; 288 | DELETE FROM fdw520; 289 | DROP FOREIGN TABLE fdw519_ft1; 290 | DROP FOREIGN TABLE fdw519_ft2; 291 | DROP FOREIGN TABLE fdw519_ft3; 292 | DROP FOREIGN TABLE fdw519_ft4; 293 | DROP FOREIGN TABLE fdw519_ft5; 294 | DROP FOREIGN TABLE fdw520; 295 | DROP USER MAPPING FOR public SERVER mysql_svr; 296 | DROP SERVER mysql_svr; 297 | DROP USER MAPPING FOR public SERVER mysql_svr1; 298 | DROP SERVER mysql_svr1; 299 | DROP EXTENSION mysql_fdw; 300 | -------------------------------------------------------------------------------- /mysql_query.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * mysql_query.c 4 | * Type handling for remote MySQL servers 5 | * 6 | * Portions Copyright (c) 2012-2014, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 2004-2025, EnterpriseDB Corporation. 8 | * 9 | * IDENTIFICATION 10 | * mysql_query.c 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | #include "postgres.h" 15 | 16 | /* 17 | * Must be included before mysql.h as it has some conflicting definitions like 18 | * list_length, etc. 19 | */ 20 | #include "mysql_fdw.h" 21 | 22 | #include 23 | #include 24 | #include 25 | #include 26 | 27 | #include "access/htup_details.h" 28 | #include "catalog/pg_type.h" 29 | #include "mysql_query.h" 30 | #include "optimizer/optimizer.h" 31 | #include "utils/builtins.h" 32 | #include "utils/date.h" 33 | #include "utils/datetime.h" 34 | #include "utils/lsyscache.h" 35 | #include "utils/syscache.h" 36 | 37 | #define DATE_MYSQL_PG(x, y) \ 38 | do { \ 39 | x->year = y.tm_year; \ 40 | x->month = y.tm_mon; \ 41 | x->day= y.tm_mday; \ 42 | x->hour = y.tm_hour; \ 43 | x->minute = y.tm_min; \ 44 | x->second = y.tm_sec; \ 45 | } while(0); 46 | 47 | static int32 mysql_from_pgtyp(Oid type); 48 | static int dec_bin(int number); 49 | static int bin_dec(int binarynumber); 50 | 51 | 52 | /* 53 | * convert_mysql_to_pg: 54 | * Convert MySQL data into PostgreSQL's compatible data types 55 | */ 56 | Datum 57 | mysql_convert_to_pg(Oid pgtyp, int pgtypmod, mysql_column *column) 58 | { 59 | Datum value_datum; 60 | Datum valueDatum; 61 | regproc typeinput; 62 | HeapTuple tuple; 63 | char str[MAXDATELEN]; 64 | bytea *result; 65 | char *text_result = NULL; 66 | 67 | /* get the type's output function */ 68 | tuple = SearchSysCache1(TYPEOID, ObjectIdGetDatum(pgtyp)); 69 | if (!HeapTupleIsValid(tuple)) 70 | elog(ERROR, "cache lookup failed for type%u", pgtyp); 71 | 72 | typeinput = ((Form_pg_type) GETSTRUCT(tuple))->typinput; 73 | ReleaseSysCache(tuple); 74 | 75 | switch (pgtyp) 76 | { 77 | /* 78 | * MySQL gives BIT / BIT(n) data type as decimal value. The only way 79 | * to retrieve this value is to use BIN, OCT or HEX function in MySQL, 80 | * otherwise mysql client shows the actual decimal value, which could 81 | * be a non - printable character. For exmple in MySQL 82 | * 83 | * CREATE TABLE t (b BIT(8)); 84 | * INSERT INTO t SET b = b'1001'; 85 | * SELECT BIN(b) FROM t; 86 | * +--------+ 87 | * | BIN(b) | 88 | * +--------+ 89 | * | 1001 | 90 | * +--------+ 91 | * 92 | * PostgreSQL expacts all binary data to be composed of either '0' or 93 | * '1'. MySQL gives value 9 hence PostgreSQL reports error. The 94 | * solution is to convert the decimal number into equivalent binary 95 | * string. 96 | */ 97 | case BYTEAOID: 98 | result = (bytea *) palloc(column->length + VARHDRSZ); 99 | memcpy(VARDATA(result), VARDATA(column->value), column->length); 100 | SET_VARSIZE(result, column->length + VARHDRSZ); 101 | return PointerGetDatum(result); 102 | 103 | case BITOID: 104 | sprintf(str, "%d", dec_bin(*((int *) column->value))); 105 | valueDatum = CStringGetDatum((char *) str); 106 | break; 107 | 108 | case TEXTOID: 109 | text_result = (char *) palloc(column->length + 1); 110 | memcpy(text_result, (char *) column->value, column->length); 111 | text_result[column->length] = '\0'; 112 | valueDatum = CStringGetDatum((char *) text_result); 113 | break; 114 | 115 | default: 116 | valueDatum = CStringGetDatum((char *) column->value); 117 | } 118 | 119 | value_datum = OidFunctionCall3(typeinput, valueDatum, 120 | ObjectIdGetDatum(pgtyp), 121 | Int32GetDatum(pgtypmod)); 122 | 123 | if (text_result) 124 | pfree(text_result); 125 | 126 | return value_datum; 127 | } 128 | 129 | /* 130 | * mysql_from_pgtyp: 131 | * Give MySQL data type for PG type 132 | */ 133 | static int32 134 | mysql_from_pgtyp(Oid type) 135 | { 136 | switch (type) 137 | { 138 | case INT2OID: 139 | return MYSQL_TYPE_SHORT; 140 | case INT4OID: 141 | return MYSQL_TYPE_LONG; 142 | case INT8OID: 143 | return MYSQL_TYPE_LONGLONG; 144 | case FLOAT4OID: 145 | return MYSQL_TYPE_FLOAT; 146 | case FLOAT8OID: 147 | return MYSQL_TYPE_DOUBLE; 148 | case NUMERICOID: 149 | return MYSQL_TYPE_DOUBLE; 150 | case BOOLOID: 151 | return MYSQL_TYPE_LONG; 152 | case BPCHAROID: 153 | case VARCHAROID: 154 | case TEXTOID: 155 | case JSONOID: 156 | case ANYENUMOID: 157 | return MYSQL_TYPE_STRING; 158 | case NAMEOID: 159 | return MYSQL_TYPE_STRING; 160 | case DATEOID: 161 | return MYSQL_TYPE_DATE; 162 | case TIMEOID: 163 | case TIMESTAMPOID: 164 | case TIMESTAMPTZOID: 165 | return MYSQL_TYPE_TIMESTAMP; 166 | case BITOID: 167 | return MYSQL_TYPE_LONG; 168 | case BYTEAOID: 169 | return MYSQL_TYPE_BLOB; 170 | default: 171 | ereport(ERROR, 172 | (errcode(ERRCODE_FDW_INVALID_DATA_TYPE), 173 | errmsg("cannot convert constant value to MySQL value"), 174 | errhint("Constant value data type: %u", type))); 175 | break; 176 | } 177 | } 178 | 179 | /* 180 | * bind_sql_var: 181 | * Bind the values provided as DatumBind the values and nulls to 182 | * modify the target table (INSERT/UPDATE) 183 | */ 184 | void 185 | mysql_bind_sql_var(Oid type, int attnum, Datum value, MYSQL_BIND *binds, 186 | bool *isnull) 187 | { 188 | /* Clear the bind buffer and attributes */ 189 | memset(&binds[attnum], 0x0, sizeof(MYSQL_BIND)); 190 | 191 | #if MYSQL_VERSION_ID < 80000 || MARIADB_VERSION_ID >= 100000 192 | binds[attnum].is_null = (my_bool *) isnull; 193 | #else 194 | binds[attnum].is_null = isnull; 195 | #endif 196 | 197 | /* Avoid to bind buffer in case value is NULL */ 198 | if (*isnull) 199 | return; 200 | 201 | /* 202 | * If type is an enum, use ANYENUMOID. We will send string containing the 203 | * enum value to the MySQL. 204 | */ 205 | if (type_is_enum(type)) 206 | type = ANYENUMOID; 207 | 208 | /* Assign the buffer type if value is not null */ 209 | binds[attnum].buffer_type = mysql_from_pgtyp(type); 210 | 211 | switch (type) 212 | { 213 | case INT2OID: 214 | { 215 | int16 dat = DatumGetInt16(value); 216 | int16 *bufptr = palloc(sizeof(int16)); 217 | 218 | memcpy(bufptr, (char *) &dat, sizeof(int16)); 219 | 220 | binds[attnum].buffer = bufptr; 221 | } 222 | break; 223 | case INT4OID: 224 | { 225 | int32 dat = DatumGetInt32(value); 226 | int32 *bufptr = palloc(sizeof(int32)); 227 | 228 | memcpy(bufptr, (char *) &dat, sizeof(int32)); 229 | 230 | binds[attnum].buffer = bufptr; 231 | } 232 | break; 233 | case INT8OID: 234 | { 235 | int64 dat = DatumGetInt64(value); 236 | int64 *bufptr = palloc(sizeof(int64)); 237 | 238 | memcpy(bufptr, (char *) &dat, sizeof(int64)); 239 | 240 | binds[attnum].buffer = bufptr; 241 | } 242 | break; 243 | case FLOAT4OID: 244 | { 245 | float4 dat = DatumGetFloat4(value); 246 | float4 *bufptr = palloc(sizeof(float4)); 247 | 248 | memcpy(bufptr, (char *) &dat, sizeof(float4)); 249 | 250 | binds[attnum].buffer = bufptr; 251 | } 252 | break; 253 | case FLOAT8OID: 254 | { 255 | float8 dat = DatumGetFloat8(value); 256 | float8 *bufptr = palloc(sizeof(float8)); 257 | 258 | memcpy(bufptr, (char *) &dat, sizeof(float8)); 259 | 260 | binds[attnum].buffer = bufptr; 261 | } 262 | break; 263 | case NUMERICOID: 264 | { 265 | Datum valueDatum = DirectFunctionCall1(numeric_float8, 266 | value); 267 | float8 dat = DatumGetFloat8(valueDatum); 268 | float8 *bufptr = palloc(sizeof(float8)); 269 | 270 | memcpy(bufptr, (char *) &dat, sizeof(float8)); 271 | 272 | binds[attnum].buffer = bufptr; 273 | } 274 | break; 275 | case BOOLOID: 276 | { 277 | int32 dat = DatumGetInt32(value); 278 | int32 *bufptr = palloc(sizeof(int32)); 279 | 280 | memcpy(bufptr, (char *) &dat, sizeof(int32)); 281 | 282 | binds[attnum].buffer = bufptr; 283 | } 284 | break; 285 | case BPCHAROID: 286 | case VARCHAROID: 287 | case TEXTOID: 288 | case JSONOID: 289 | case ANYENUMOID: 290 | { 291 | char *outputString = NULL; 292 | Oid outputFunctionId = InvalidOid; 293 | bool typeVarLength = false; 294 | 295 | getTypeOutputInfo(type, &outputFunctionId, &typeVarLength); 296 | outputString = OidOutputFunctionCall(outputFunctionId, value); 297 | 298 | binds[attnum].buffer = outputString; 299 | binds[attnum].buffer_length = strlen(outputString); 300 | } 301 | break; 302 | case NAMEOID: 303 | { 304 | char *outputString = NULL; 305 | Oid outputFunctionId = InvalidOid; 306 | bool typeVarLength = false; 307 | 308 | getTypeOutputInfo(type, &outputFunctionId, &typeVarLength); 309 | outputString = OidOutputFunctionCall(outputFunctionId, value); 310 | 311 | binds[attnum].buffer = outputString; 312 | binds[attnum].buffer_length = strlen(outputString); 313 | } 314 | break; 315 | case DATEOID: 316 | { 317 | int tz; 318 | struct pg_tm tt, 319 | *tm = &tt; 320 | fsec_t fsec; 321 | const char *tzn; 322 | Datum valueDatum = DirectFunctionCall1(date_timestamp, 323 | value); 324 | Timestamp valueTimestamp = DatumGetTimestamp(valueDatum); 325 | MYSQL_TIME *ts = palloc0(sizeof(MYSQL_TIME)); 326 | 327 | timestamp2tm(valueTimestamp, &tz, tm, &fsec, &tzn, 328 | pg_tzset("UTC")); 329 | 330 | DATE_MYSQL_PG(ts, tt); 331 | 332 | binds[attnum].buffer = ts; 333 | binds[attnum].buffer_length = sizeof(MYSQL_TIME); 334 | } 335 | break; 336 | case TIMEOID: 337 | case TIMESTAMPOID: 338 | case TIMESTAMPTZOID: 339 | { 340 | Timestamp valueTimestamp = DatumGetTimestamp(value); 341 | MYSQL_TIME *ts = palloc0(sizeof(MYSQL_TIME)); 342 | int tz; 343 | struct pg_tm tt, 344 | *tm = &tt; 345 | fsec_t fsec; 346 | const char *tzn; 347 | 348 | timestamp2tm(valueTimestamp, &tz, tm, &fsec, &tzn, 349 | pg_tzset("UTC")); 350 | 351 | DATE_MYSQL_PG(ts, tt); 352 | 353 | binds[attnum].buffer = ts; 354 | binds[attnum].buffer_length = sizeof(MYSQL_TIME); 355 | } 356 | break; 357 | case BITOID: 358 | { 359 | int32 dat; 360 | int32 *bufptr = palloc0(sizeof(int32)); 361 | char *outputString = NULL; 362 | Oid outputFunctionId = InvalidOid; 363 | bool typeVarLength = false; 364 | 365 | getTypeOutputInfo(type, &outputFunctionId, &typeVarLength); 366 | outputString = OidOutputFunctionCall(outputFunctionId, value); 367 | 368 | dat = bin_dec(atoi(outputString)); 369 | memcpy(bufptr, (char *) &dat, sizeof(int32)); 370 | binds[attnum].buffer = bufptr; 371 | } 372 | break; 373 | case BYTEAOID: 374 | { 375 | int len; 376 | char *dat = NULL; 377 | char *bufptr; 378 | char *result = DatumGetPointer(value); 379 | 380 | if (VARATT_IS_1B(result)) 381 | { 382 | len = VARSIZE_1B(result) - VARHDRSZ_SHORT; 383 | dat = VARDATA_1B(result); 384 | } 385 | else 386 | { 387 | len = VARSIZE_4B(result) - VARHDRSZ; 388 | dat = VARDATA_4B(result); 389 | } 390 | 391 | bufptr = palloc(len); 392 | memcpy(bufptr, (char *) dat, len); 393 | binds[attnum].buffer = bufptr; 394 | binds[attnum].buffer_length = len; 395 | } 396 | break; 397 | default: 398 | ereport(ERROR, 399 | (errcode(ERRCODE_FDW_INVALID_DATA_TYPE), 400 | errmsg("cannot convert constant value to MySQL value"), 401 | errhint("Constant value data type: %u", type))); 402 | break; 403 | } 404 | } 405 | 406 | /* 407 | * mysql_bind_result: 408 | * Bind the value and null pointers to get the data from 409 | * remote mysql table (SELECT) 410 | */ 411 | void 412 | mysql_bind_result(Oid pgtyp, int pgtypmod, MYSQL_FIELD *field, 413 | mysql_column *column) 414 | { 415 | MYSQL_BIND *mbind = column->mysql_bind; 416 | 417 | memset(mbind, 0, sizeof(MYSQL_BIND)); 418 | 419 | #if MYSQL_VERSION_ID < 80000 || MARIADB_VERSION_ID >= 100000 420 | mbind->is_null = (my_bool *) &column->is_null; 421 | mbind->error = (my_bool *) &column->error; 422 | #else 423 | mbind->is_null = &column->is_null; 424 | mbind->error = &column->error; 425 | #endif 426 | mbind->length = &column->length; 427 | 428 | switch (pgtyp) 429 | { 430 | case BYTEAOID: 431 | mbind->buffer_type = MYSQL_TYPE_BLOB; 432 | /* Leave room at front for bytea buffer length prefix */ 433 | column->value = (Datum) palloc0(MAX_BLOB_WIDTH + VARHDRSZ); 434 | mbind->buffer = VARDATA(column->value); 435 | mbind->buffer_length = MAX_BLOB_WIDTH; 436 | break; 437 | case TEXTOID: 438 | mbind->buffer_type = MYSQL_TYPE_VAR_STRING; 439 | if (field->max_length == 0) 440 | { 441 | column->value = (Datum) palloc0(MAXDATALEN); 442 | mbind->buffer_length = MAXDATALEN; 443 | } 444 | else 445 | { 446 | column->value = (Datum) palloc0(field->max_length); 447 | mbind->buffer_length = field->max_length; 448 | } 449 | mbind->buffer = (char *) column->value; 450 | break; 451 | default: 452 | mbind->buffer_type = MYSQL_TYPE_VAR_STRING; 453 | column->value = (Datum) palloc0(MAXDATALEN); 454 | mbind->buffer = (char *) column->value; 455 | mbind->buffer_length = MAXDATALEN; 456 | } 457 | } 458 | 459 | static int 460 | dec_bin(int number) 461 | { 462 | int rem; 463 | int i = 1; 464 | int bin = 0; 465 | 466 | while (number != 0) 467 | { 468 | rem = number % 2; 469 | number /= 2; 470 | bin += rem * i; 471 | i *= 10; 472 | } 473 | 474 | return bin; 475 | } 476 | 477 | static int 478 | bin_dec(int binarynumber) 479 | { 480 | int dec = 0; 481 | int i = 0; 482 | int rem; 483 | 484 | while (binarynumber != 0) 485 | { 486 | rem = binarynumber % 10; 487 | binarynumber /= 10; 488 | dec += rem * pow(2, i); 489 | ++i; 490 | } 491 | 492 | return dec; 493 | } 494 | -------------------------------------------------------------------------------- /mysql_fdw.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * mysql_fdw.h 4 | * Foreign-data wrapper for remote MySQL servers 5 | * 6 | * Portions Copyright (c) 2012-2014, PostgreSQL Global Development Group 7 | * Portions Copyright (c) 2004-2025, EnterpriseDB Corporation. 8 | * 9 | * IDENTIFICATION 10 | * mysql_fdw.h 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | #ifndef MYSQL_FDW_H 15 | #define MYSQL_FDW_H 16 | 17 | #define list_length mysql_list_length 18 | #define list_delete mysql_list_delete 19 | #define list_free mysql_list_free 20 | 21 | #include 22 | #undef list_length 23 | #undef list_delete 24 | #undef list_free 25 | 26 | #include "access/tupdesc.h" 27 | #include "fmgr.h" 28 | #include "foreign/foreign.h" 29 | #include "funcapi.h" 30 | #include "lib/stringinfo.h" 31 | #include "nodes/pathnodes.h" 32 | #include "utils/rel.h" 33 | 34 | #define MYSQL_PREFETCH_ROWS 100 35 | #define MYSQL_BLKSIZ (1024 * 4) 36 | #define MYSQL_SERVER_PORT 3306 37 | #define MAXDATALEN 1024 * 64 38 | 39 | #define WAIT_TIMEOUT 0 40 | #define INTERACTIVE_TIMEOUT 0 41 | 42 | #define CR_NO_ERROR 0 43 | 44 | #define mysql_options (*_mysql_options) 45 | #define mysql_stmt_prepare (*_mysql_stmt_prepare) 46 | #define mysql_stmt_execute (*_mysql_stmt_execute) 47 | #define mysql_stmt_fetch (*_mysql_stmt_fetch) 48 | #define mysql_query (*_mysql_query) 49 | #define mysql_stmt_attr_set (*_mysql_stmt_attr_set) 50 | #define mysql_stmt_close (*_mysql_stmt_close) 51 | #define mysql_stmt_reset (*_mysql_stmt_reset) 52 | #define mysql_free_result (*_mysql_free_result) 53 | #define mysql_stmt_bind_param (*_mysql_stmt_bind_param) 54 | #define mysql_stmt_bind_result (*_mysql_stmt_bind_result) 55 | #define mysql_stmt_init (*_mysql_stmt_init) 56 | #define mysql_stmt_result_metadata (*_mysql_stmt_result_metadata) 57 | #define mysql_stmt_store_result (*_mysql_stmt_store_result) 58 | #define mysql_fetch_row (*_mysql_fetch_row) 59 | #define mysql_fetch_field (*_mysql_fetch_field) 60 | #define mysql_fetch_fields (*_mysql_fetch_fields) 61 | #define mysql_error (*_mysql_error) 62 | #define mysql_close (*_mysql_close) 63 | #define mysql_store_result (*_mysql_store_result) 64 | #define mysql_init (*_mysql_init) 65 | #define mysql_ssl_set (*_mysql_ssl_set) 66 | #define mysql_real_connect (*_mysql_real_connect) 67 | #define mysql_get_host_info (*_mysql_get_host_info) 68 | #define mysql_get_server_info (*_mysql_get_server_info) 69 | #define mysql_get_proto_info (*_mysql_get_proto_info) 70 | #define mysql_stmt_errno (*_mysql_stmt_errno) 71 | #define mysql_errno (*_mysql_errno) 72 | #define mysql_num_fields (*_mysql_num_fields) 73 | #define mysql_num_rows (*_mysql_num_rows) 74 | 75 | /* Macro for list API backporting. */ 76 | #define mysql_list_concat(l1, l2) list_concat((l1), (l2)) 77 | 78 | /* 79 | * Options structure to store the MySQL 80 | * server information 81 | */ 82 | typedef struct mysql_opt 83 | { 84 | int svr_port; /* MySQL port number */ 85 | char *svr_address; /* MySQL server ip address */ 86 | char *svr_username; /* MySQL user name */ 87 | char *svr_password; /* MySQL password */ 88 | char *svr_database; /* MySQL database name */ 89 | char *svr_table; /* MySQL table name */ 90 | bool svr_sa; /* MySQL secure authentication */ 91 | char *svr_init_command; /* MySQL SQL statement to execute when 92 | * connecting to the MySQL server. */ 93 | unsigned long max_blob_size; /* Max blob size to read without 94 | * truncation */ 95 | bool use_remote_estimate; /* use remote estimate for rows */ 96 | unsigned long fetch_size; /* Number of rows to fetch from remote server */ 97 | bool reconnect; /* set to true for automatic reconnection */ 98 | char *character_set; /* Character set used for remote connection */ 99 | char *sql_mode; /* MySQL sql_mode variable for connection */ 100 | char *mysql_default_file; /* Path of a file from which connection 101 | * options are to be read */ 102 | 103 | /* SSL parameters; unused options may be given as NULL */ 104 | char *ssl_key; /* MySQL SSL: path to the key file */ 105 | char *ssl_cert; /* MySQL SSL: path to the certificate file */ 106 | char *ssl_ca; /* MySQL SSL: path to the certificate 107 | * authority file */ 108 | char *ssl_capath; /* MySQL SSL: path to a directory that 109 | * contains trusted SSL CA certificates in PEM 110 | * format */ 111 | char *ssl_cipher; /* MySQL SSL: list of permissible ciphers to 112 | * use for SSL encryption */ 113 | } mysql_opt; 114 | 115 | typedef struct mysql_column 116 | { 117 | Datum value; 118 | unsigned long length; 119 | bool is_null; 120 | bool error; 121 | MYSQL_BIND *mysql_bind; 122 | } mysql_column; 123 | 124 | typedef struct mysql_table 125 | { 126 | MYSQL_RES *mysql_res; 127 | MYSQL_FIELD *mysql_fields; 128 | mysql_column *column; 129 | MYSQL_BIND *mysql_bind; 130 | } mysql_table; 131 | 132 | /* 133 | * Structure to hold information for constructing a whole-row reference value 134 | * for a single base relation involved in a pushed down join. 135 | */ 136 | typedef struct 137 | { 138 | /* 139 | * Tuple descriptor for whole-row reference. We can not use the base 140 | * relation's tuple descriptor as it is, since it might have information 141 | * about dropped attributes. 142 | */ 143 | TupleDesc tupdesc; 144 | 145 | /* 146 | * Positions of the required attributes in the tuple fetched from the 147 | * foreign server. 148 | */ 149 | int *attr_pos; 150 | 151 | /* Position of attribute indicating NULL-ness of whole-row reference */ 152 | int wr_null_ind_pos; 153 | 154 | /* Values and null array for holding column values. */ 155 | Datum *values; 156 | bool *nulls; 157 | } MySQLWRState; 158 | 159 | /* 160 | * FDW-specific information for ForeignScanState 161 | * fdw_state. 162 | */ 163 | typedef struct MySQLFdwExecState 164 | { 165 | MYSQL *conn; /* MySQL connection handle */ 166 | MYSQL_STMT *stmt; /* MySQL prepared stament handle */ 167 | mysql_table *table; 168 | char *query; /* Query string */ 169 | List *retrieved_attrs; /* list of target attribute numbers */ 170 | bool query_executed; /* have we executed the query? */ 171 | int numParams; /* number of parameters passed to query */ 172 | FmgrInfo *param_flinfo; /* output conversion functions for them */ 173 | List *param_exprs; /* executable expressions for param values */ 174 | const char **param_values; /* textual values of query parameters */ 175 | Oid *param_types; /* type of query parameters */ 176 | int p_nums; /* number of parameters to transmit */ 177 | FmgrInfo *p_flinfo; /* output conversion functions for them */ 178 | mysql_opt *mysqlFdwOptions; /* MySQL FDW options */ 179 | MemoryContext temp_cxt; /* context for per-tuple temporary data */ 180 | AttInMetadata *attinmeta; 181 | AttrNumber rowidAttno; /* attnum of resjunk rowid column */ 182 | bool has_var_size_col; /* true if fetching var size columns */ 183 | 184 | /* 185 | * Members used for constructing the ForeignScan result row when whole-row 186 | * references are involved in a pushed down join. 187 | */ 188 | MySQLWRState **mysqlwrstates; /* whole-row construction information for 189 | * each base relation involved in the 190 | * pushed down join. */ 191 | int *wr_attrs_pos; /* Array mapping the attributes in the 192 | * ForeignScan result to those in the rows 193 | * fetched from the foreign server. The array 194 | * is indexed by the attribute numbers in the 195 | * ForeignScan. */ 196 | TupleDesc wr_tupdesc; /* Tuple descriptor describing the result of 197 | * ForeignScan node. Should be same as that 198 | * in ForeignScanState::ss::ss_ScanTupleSlot */ 199 | /* Array for holding column values. */ 200 | Datum *wr_values; 201 | bool *wr_nulls; 202 | } MySQLFdwExecState; 203 | 204 | typedef struct MySQLFdwRelationInfo 205 | { 206 | /* 207 | * True means that the relation can be pushed down. Always true for simple 208 | * foreign scan. 209 | */ 210 | bool pushdown_safe; 211 | 212 | /* baserestrictinfo clauses, broken down into safe and unsafe subsets. */ 213 | List *remote_conds; 214 | List *local_conds; 215 | 216 | /* Bitmap of attr numbers we need to fetch from the remote server. */ 217 | Bitmapset *attrs_used; 218 | 219 | /* True means that the query_pathkeys is safe to push down */ 220 | bool qp_is_pushdown_safe; 221 | 222 | /* 223 | * Name of the relation while EXPLAINing ForeignScan. It is used for join 224 | * relations but is set for all relations. For join relation, the name 225 | * indicates which foreign tables are being joined and the join type used. 226 | */ 227 | StringInfo relation_name; 228 | 229 | /* Join information */ 230 | RelOptInfo *outerrel; 231 | RelOptInfo *innerrel; 232 | JoinType jointype; 233 | List *joinclauses; 234 | /* Grouping information */ 235 | List *grouped_tlist; 236 | 237 | /* Upper relation information */ 238 | UpperRelationKind stage; 239 | } MySQLFdwRelationInfo; 240 | 241 | 242 | /* MySQL Column List */ 243 | typedef struct MySQLColumn 244 | { 245 | int attnum; /* Attribute number */ 246 | char *attname; /* Attribute name */ 247 | int atttype; /* Attribute type */ 248 | } MySQLColumn; 249 | 250 | 251 | extern int ((mysql_options) (MYSQL *mysql, enum mysql_option option, 252 | const void *arg)); 253 | extern int ((mysql_stmt_prepare) (MYSQL_STMT *stmt, const char *query, 254 | unsigned long length)); 255 | extern int ((mysql_stmt_execute) (MYSQL_STMT *stmt)); 256 | extern int ((mysql_stmt_fetch) (MYSQL_STMT *stmt)); 257 | extern int ((mysql_query) (MYSQL *mysql, const char *q)); 258 | extern bool ((mysql_stmt_attr_set) (MYSQL_STMT *stmt, 259 | enum enum_stmt_attr_type attr_type, 260 | const void *attr)); 261 | extern bool ((mysql_stmt_close) (MYSQL_STMT *stmt)); 262 | extern bool ((mysql_stmt_reset) (MYSQL_STMT *stmt)); 263 | extern bool ((mysql_free_result) (MYSQL_RES *result)); 264 | extern bool ((mysql_stmt_bind_param) (MYSQL_STMT *stmt, MYSQL_BIND *bnd)); 265 | extern bool ((mysql_stmt_bind_result) (MYSQL_STMT *stmt, MYSQL_BIND *bnd)); 266 | 267 | extern MYSQL_STMT *((mysql_stmt_init) (MYSQL *mysql)); 268 | extern MYSQL_RES *((mysql_stmt_result_metadata) (MYSQL_STMT *stmt)); 269 | extern int ((mysql_stmt_store_result) (MYSQL_STMT *stmt)); 270 | extern MYSQL_ROW((mysql_fetch_row) (MYSQL_RES *result)); 271 | extern MYSQL_FIELD *((mysql_fetch_field) (MYSQL_RES *result)); 272 | extern MYSQL_FIELD *((mysql_fetch_fields) (MYSQL_RES *result)); 273 | extern const char *((mysql_error) (MYSQL *mysql)); 274 | extern void ((mysql_close) (MYSQL *sock)); 275 | extern MYSQL_RES *((mysql_store_result) (MYSQL *mysql)); 276 | extern MYSQL *((mysql_init) (MYSQL *mysql)); 277 | extern bool ((mysql_ssl_set) (MYSQL *mysql, const char *key, const char *cert, 278 | const char *ca, const char *capath, 279 | const char *cipher)); 280 | extern MYSQL *((mysql_real_connect) (MYSQL *mysql, const char *host, 281 | const char *user, const char *passwd, 282 | const char *db, unsigned int port, 283 | const char *unix_socket, 284 | unsigned long clientflag)); 285 | 286 | extern const char *((mysql_get_host_info) (MYSQL *mysql)); 287 | extern const char *((mysql_get_server_info) (MYSQL *mysql)); 288 | extern int ((mysql_get_proto_info) (MYSQL *mysql)); 289 | 290 | extern unsigned int ((mysql_stmt_errno) (MYSQL_STMT *stmt)); 291 | extern unsigned int ((mysql_errno) (MYSQL *mysql)); 292 | extern unsigned int ((mysql_num_fields) (MYSQL_RES *result)); 293 | extern unsigned int ((mysql_num_rows) (MYSQL_RES *result)); 294 | 295 | 296 | /* option.c headers */ 297 | extern bool mysql_is_valid_option(const char *option, Oid context); 298 | extern mysql_opt *mysql_get_options(Oid foreigntableid, bool is_foreigntable); 299 | 300 | /* depare.c headers */ 301 | extern void mysql_deparse_insert(StringInfo buf, PlannerInfo *root, 302 | Index rtindex, Relation rel, 303 | List *targetAttrs, bool doNothing); 304 | extern void mysql_deparse_update(StringInfo buf, PlannerInfo *root, 305 | Index rtindex, Relation rel, 306 | List *targetAttrs, char *attname); 307 | extern void mysql_deparse_delete(StringInfo buf, PlannerInfo *root, 308 | Index rtindex, Relation rel, char *name); 309 | extern void mysql_deparse_analyze(StringInfo buf, char *dbname, char *relname); 310 | extern bool mysql_is_foreign_expr(PlannerInfo *root, RelOptInfo *baserel, 311 | Expr *expr, bool is_remote_cond); 312 | extern void mysql_deparse_select_stmt_for_rel(StringInfo buf, 313 | PlannerInfo *root, 314 | RelOptInfo *rel, List *tlist, 315 | List *remote_conds, 316 | List *pathkeys, 317 | bool has_final_sort, 318 | bool has_limit, 319 | List **retrieved_attrs, 320 | List **params_list); 321 | extern const char *mysql_get_jointype_name(JoinType jointype); 322 | extern bool mysql_is_foreign_param(PlannerInfo *root, RelOptInfo *baserel, 323 | Expr *expr); 324 | extern bool mysql_is_foreign_pathkey(PlannerInfo *root, RelOptInfo *baserel, 325 | PathKey *pathkey); 326 | extern char *mysql_get_sortby_direction_string(EquivalenceMember *em, 327 | PathKey *pathkey); 328 | extern EquivalenceMember *mysql_find_em_for_rel(PlannerInfo *root, 329 | EquivalenceClass *ec, 330 | RelOptInfo *rel); 331 | extern EquivalenceMember *mysql_find_em_for_rel_target(PlannerInfo *root, 332 | EquivalenceClass *ec, 333 | RelOptInfo *rel); 334 | extern bool mysql_is_builtin(Oid objectId); 335 | #if PG_VERSION_NUM >= 140000 336 | extern void mysql_deparse_truncate_sql(StringInfo buf, Relation rel); 337 | #endif 338 | extern char *mysql_quote_identifier(const char *str, char quotechar); 339 | 340 | /* connection.c headers */ 341 | MYSQL *mysql_get_connection(ForeignServer *server, UserMapping *user, 342 | mysql_opt *opt); 343 | MYSQL *mysql_fdw_connect(mysql_opt *opt); 344 | void mysql_cleanup_connection(void); 345 | void mysql_release_connection(MYSQL *conn); 346 | 347 | #endif /* MYSQL_FDW_H */ 348 | --------------------------------------------------------------------------------