Implement support for MySQL SET parameters.

pgloader had support for PostgreSQL SET parameters (gucs) from the
beginning, and in the same vein it might be necessary to tweak MySQL
connection parameters, and allow pgloader users to control them.

See #337 and #420 where net_read_timeout and net_write_timeout might need to
be set in order to be able to complete the migration, due to high volumes of
data being processed.
This commit is contained in:
Dimitri Fontaine 2017-06-27 10:00:47 +02:00
parent b5a593af14
commit 352f4adc8d
9 changed files with 65 additions and 15 deletions

View File

@ -1805,9 +1805,14 @@ LOAD DATABASE
WITH include drop, create tables, create indexes, reset sequences,
workers = 8, concurrency = 1
SET maintenance_work_mem to \'128MB\',
SET PostgreSQL PARAMETERS
maintenance_work_mem to \'128MB\',
work_mem to \'12MB\',
search_path to \'sakila\'
search_path to \'sakila, public, "$user"\'
SET MySQL PARAMETERS
net_read_timeout = \'120\',
net_write_timeout = \'120\'
CAST type datetime to timestamptz drop default drop not null using zero\-dates\-to\-null,
type date drop not null drop default using zero\-dates\-to\-null,
@ -2000,6 +2005,12 @@ When this option is listed pgloader only issues the \fBCOPY\fR statements, witho
.
.IP "" 0
.
.IP "\(bu" 4
\fISET MySQL PARAMETERS\fR
.
.IP
The \fISET MySQL PARAMETERS\fR allows setting MySQL parameters using the MySQL \fBSET\fR command each time pgloader connects to it\.
.
.IP "\(bu" 4
\fICAST\fR

View File

@ -1541,9 +1541,14 @@ Here's an example:
WITH include drop, create tables, create indexes, reset sequences,
workers = 8, concurrency = 1
SET maintenance_work_mem to '128MB',
SET PostgreSQL PARAMETERS
maintenance_work_mem to '128MB',
work_mem to '12MB',
search_path to 'sakila'
search_path to 'sakila, public, "$user"'
SET MySQL PARAMETERS
net_read_timeout = '120',
net_write_timeout = '120'
CAST type datetime to timestamptz drop default drop not null using zero-dates-to-null,
type date drop not null drop default using zero-dates-to-null,
@ -1742,6 +1747,11 @@ The `database` command accepts the following clauses and options:
When this option is listed pgloader only issues the `COPY`
statements, without doing any other processing.
- *SET MySQL PARAMETERS*
The *SET MySQL PARAMETERS* allows setting MySQL parameters using the
MySQL `SET` command each time pgloader connects to it.
- *CAST*
The cast clause allows to specify custom casting rules, either to

View File

@ -24,6 +24,7 @@
#:*copy-batch-size*
#:*concurrent-batches*
#:*pg-settings*
#:*mysql-settings*
#:*default-tmpdir*
#:init-params-from-environment
#:getenv-default
@ -136,6 +137,7 @@
"How many batches do we stack in the queue in advance.")
(defparameter *pg-settings* nil "An alist of GUC names and values.")
(defparameter *mysql-settings* nil "An alist of GUC names and values.")
;;;
;;; Archive processing: downloads and unzip.

View File

@ -51,6 +51,7 @@
(def-keyword-rule "on")
(def-keyword-rule "error")
(def-keyword-rule "stop")
(def-keyword-rule "parameters")
;; option for loading from a file
(def-keyword-rule "workers")
(def-keyword-rule "batch")
@ -145,3 +146,5 @@
(defrule kw-auto-increment (and "auto_increment" (* (or #\Tab #\Space)))
(:constant :auto-increment))
(defrule kw-postgresql (or (~ "pgsql") (~ "postgresql")))
(defrule kw-mysql (~ "mysql"))

View File

@ -61,11 +61,19 @@
(:lambda (tables)
(cons :decoding tables)))
;;;
;;; MySQL SET parameters, because sometimes we need that
;;;
(defrule mysql-gucs (and kw-set kw-mysql kw-parameters generic-option-list)
(:lambda (mygucs) (cons :mysql-gucs (fourth mygucs))))
;;;
;;; Allow clauses to appear in any order
;;;
(defrule load-mysql-optional-clauses (* (or mysql-options
mysql-gucs
gucs
casts
alter-table
@ -140,7 +148,8 @@
(defun lisp-code-for-loading-from-mysql (my-db-conn pg-db-conn
&key
gucs casts views before after options
gucs mysql-gucs
casts views before after options
alter-table alter-schema
((:including incl))
((:excluding excl))
@ -149,6 +158,7 @@
(let* ((*default-cast-rules* ',*mysql-default-cast-rules*)
(*cast-rules* ',casts)
(*decoding-as* ',decoding-as)
(*mysql-settings* ',mysql-gucs)
,@(pgsql-connection-bindings pg-db-conn gucs)
,@(batch-control-bindings options)
,@(identifier-case-binding options)
@ -175,7 +185,7 @@
(destructuring-bind (my-db-uri
pg-db-uri
&key
gucs casts views before after options
gucs mysql-gucs casts views before after options
alter-table alter-schema
including excluding decoding)
source
@ -184,6 +194,7 @@
(t
(lisp-code-for-loading-from-mysql my-db-uri pg-db-uri
:gucs gucs
:mysql-gucs mysql-gucs
:casts casts
:views views
:before before

View File

@ -208,7 +208,9 @@
;; here we want an alist
(list* opt1 opts))))
(defrule gucs (and kw-set generic-option-list)
(defrule gucs (and kw-set
(? (and kw-postgresql kw-parameters))
generic-option-list)
(:lambda (source)
(bind (((_ gucs) source))
(bind (((_ _ gucs) source))
(cons :gucs gucs))))

View File

@ -29,6 +29,11 @@
:password (db-pass myconn)
:database (db-name myconn))))
(log-message :debug "CONNECTED TO ~a" myconn)
;; apply mysql-settings, if any
(loop :for (name . value) :in *mysql-settings*
:for sql := (format nil "set ~a = ~a;" name value)
:do (query myconn sql))
;; return the connection object
myconn)
@ -47,7 +52,7 @@
(as-text t)
(result-type 'list))
"Run SQL query against MySQL connection MYCONN."
(log-message :debug "MySQL: sending query: ~a" sql)
(log-message :sql "MySQL: sending query: ~a" sql)
(qmynd:mysql-query (conn-handle myconn)
sql
:row-fn row-fn
@ -57,14 +62,14 @@
;;;
;;; The generic API query is recent, used to look like this:
;;;
(declaim (inline mysql-query))
(defun mysql-query (query &key row-fn (as-text t) (result-type 'list))
"Execute given QUERY within the current *connection*, and set proper
defaults for pgloader."
(log-message :sql "MySQL: sending query: ~a" query)
(qmynd:mysql-query (conn-handle *connection*) query
:row-fn row-fn
:as-text as-text
:result-type result-type))
(query *connection* query
:row-fn row-fn
:as-text as-text
:result-type result-type))
;;;
;;; Function for accessing the MySQL catalogs, implementing auto-discovery.

View File

@ -12,6 +12,7 @@
(*copy-batch-size* . ,*copy-batch-size*)
(*concurrent-batches* . ,*concurrent-batches*)
(*pg-settings* . ',*pg-settings*)
(*mysql-settings* . ',*mysql-settings*)
(*root-dir* . ,*root-dir*)
(*fd-path-root* . ,*fd-path-root*)
(*client-min-messages* . ,*client-min-messages*)

View File

@ -11,10 +11,15 @@ load database
max parallel create index = 4-- ,
-- quote identifiers
SET maintenance_work_mem to '128MB',
SET PostgreSQL PARAMETERS
maintenance_work_mem to '128MB',
work_mem to '12MB',
search_path to 'sakila, public, "$user"'
SET MySQL PARAMETERS
net_read_timeout = '120',
net_write_timeout = '120'
CAST type date drop not null drop default using zero-dates-to-null,
type datetime to timestamp drop default drop not null using zero-dates-to-null