Add MariaDB to Postgres migration guide and configs

Introduces a comprehensive migration guide for moving from MariaDB to PostgreSQL, including troubleshooting and step-by-step instructions. Adds pgloader configuration files and custom transformation functions for handling data conversion, and updates mkdocs navigation to include the new migration documentation.
This commit is contained in:
João Vitória Silva
2025-10-20 22:07:46 +01:00
parent a23601b899
commit 96ed9e99c1
5 changed files with 865 additions and 0 deletions

View File

@@ -0,0 +1,240 @@
# MariaDB to Postgres migration guide
This will guide you on how to migrate from MariaDB to Postgres. Endurain will drop support for MariaDB on v0.16.0, so you'll need to perform this migration prior to upgrade to v0.16.0
This guide uses [pgloader](https://pgloader.io) to automate the migration.
This guide uses some [helper files](https://github.com/joaovitoriasilva/endurain/tree/master/docs). Refer to them when needed.
# Install pgloader
Refer to [pgloader docs](https://pgloader.readthedocs.io/en/latest/) for installation instructions.
# Migration steps
1. Stop Endurain container (`docker compose down`);
2. Backup existent database [MariaDB dump backup options](#mariadb-dump-backup-options))
3. Run pgloader to do the migration [Do the migration](#do-the-migration);
4. Verify migration by:
- Checking pgloader outputs and logs.
5. Update environment variables (adapt to your environment):
```
DB_TYPE=postgres
DB_HOST=postgres
DB_PORT=5432
```
6. Start with PostgreSQL:
```
docker compose up -d
```
7. Monitor logs for any issues;
8. Verify application functionality:
- Test login;
- Upload test activity;
- Check activity streams display;
- Verify integrations (Strava, Garmin);
- Others.
# MariaDB dump backup options
## Option 1: Run `mysqldump` / `mariadb-dump` from the host
Run the dump from your host machine (Ubuntu) using the MySQL or MariaDB client tools installed locally. You need to adjust host, port, database and password to match your environment.
```bash
mysqldump -h 127.0.0.1 -P 3306 -u endurain -p'redacted' endurain \
> final_backup_$(date +%Y%m%d_%H%M%S).sql
```
```bash
mariadb-dump -h 127.0.0.1 -P 3306 -u endurain -p'redacted' endurain \
> final_backup_$(date +%Y%m%d_%H%M%S).sql
```
**Pros:**
- No need to modify the container
- Easy to automate in cron or scripts
**Cons:**
- Requires MariaDB client installed on the host
- The containers database port must be exposed
## Option 2: Use a temporary MariaDB client container
Use a one-time client container that connects to your running MariaDB instance. You need to adjust container name, host, port, database and password to match your environment.
```bash
sudo docker run --rm \
--network container:mariadb_endurain_prod \
mariadb:latest \
mariadb-dump -h127.0.0.1 -u endurain -p'redacted' endurain \
> final_backup_$(date +%Y%m%d_%H%M%S).sql
```
**Pros:**
- Doesnt modify your running container
- Uses an official image that already includes `mariadb-dump`
**Cons:**
- Slightly longer to run (needs to pull/start the client container)
## Option 3: Install `mariadb-client` inside the existing container
If you prefer to back up directly from inside the existing MariaDB container, install the client tools and use `mariadb-dump`.
### Installation
Connect to the container shell and do:
- For Debian/Ubuntu-based containers:
```bash
apt-get update && apt-get install -y mariadb-client
```
- For Alpine-based containers:
```bash
apk add --no-cache mariadb-client
```
### Backup Command (Single Database, No GTID)
You need to adjust container name, host, port, database and password to match your environment.
```bash
sudo docker exec mariadb_endurain_prod sh -lc \
"mariadb-dump -u endurain -p'redacted' \
--databases endurain \
--single-transaction --routines --triggers --events --hex-blob" \
> final_backup_$(date +%Y%m%d_%H%M%S).sql
```
**Pros:**
- All-in-one (runs inside the existing container)
- Direct socket access to MariaDB
**Cons:**
- You modify the production container
- Must remember to reinstall client tools after container rebuilds
# Postgres preparation for pgloader
Postgres dropped support for MD5 hashed passwords in favor of SHA256, however pgloader [does not support SHA256](https://github.com/dimitri/pgloader/issues/1207). What I did was:
- Change password to be MD5 hashed:
```sql
set password_encryption to 'md5';
ALTER ROLE endurain password 'JUST_RETYPE_YOUR_EXISTING_PASSWORD';
```
- Change `pg_hba.conf` file to allow MD5 logins:
- On my machine using postgres 18 Docker image: `/opt/containers/postgres_endurain_prod/18/docker/pg_hba.conf`
```
# replication privilege.
local replication all trust
host replication all 127.0.0.1/32 trust
host replication all ::1/128 trust
# Allow MD5 just for endurain (IPv4 example). # Add this line
host all endurain 0.0.0.0/0 md5 # Add this line
host all all all scram-sha-256
```
# Do the migration
## Prerequisites and Important Notes
⚠️ **Important Notes:**
- DB passwords with special characters like `@` or `!` can cause issues;
- Recommendation: Use simple passwords during migration, change them afterward;
- The migration can be memory-intensive, especially for large `activities_streams` tables;
- Ensure sufficient RAM (at least 4GB available) on the machine running pgloader.
## Migration Process
Remember: Always keep your MariaDB backup until you're confident the PostgreSQL migration is successful and stable.
After [pgloader](https://pgloader.readthedocs.io/en/latest/) is installed:
1. **Clone Endurain repository:**
```bash
git clone https://github.com/joaovitoriasilva/endurain
cd endurain/mariadb_to_postgres
```
2. **Edit the migration configuration:**
Edit `mariadb_to_postgres_streams_only.load` and `mariadb_to_postgres_without_streams.load` to match your environment:
- Change DB connections (adjust host, port, database, user and password):
```sql
LOAD DATABASE
FROM mysql://endurain:password@mariadb-host:3306/endurain
INTO postgresql://endurain:password@postgres-host:5432/endurain
```
3. **Migration:**
The migration is splitted because activity_streams table has large json data, causing memory issues
**Step 1:** Migrate all tables except activities_streams:
```bash
pgloader --verbose --load-lisp-file transforms.lisp mariadb_to_postgres_without_streams.load > migration_main_$(date +%Y%m%d_%H%M%S).log 2>&1
```
This step may take several minutes to conclude
**Step 2:** Migrate activities_streams separately:
```bash
pgloader --verbose --load-lisp-file transforms.lisp mariadb_to_postgres_streams_only.load > migration_streams_$(date +%Y%m%d_%H%M%S).log 2>&1
```
## Revert Postgres changes
Revert changes made to user endurain:
- Change password to be SHA256 hashed:
```sql
set password_encryption to 'scram-sha-256';
ALTER ROLE endurain password 'JUST_RETYPE_YOUR_EXISTING_PASSWORD';
```
- Change `pg_hba.conf` file to allow MD5 logins:
- On my machine using postgres 18 Docker image: `/opt/containers/postgres_endurain_prod/18/docker/pg_hba.conf`
```
# replication privilege.
local replication all trust
host replication all 127.0.0.1/32 trust
host replication all ::1/128 trust
# Allow MD5 just for endurain (IPv4 example). # Remove this line
host all endurain 0.0.0.0/0 md5 # Remove this line
host all all all scram-sha-256
```
## Troubleshooting Common Issues
### Memory Exhaustion Errors
**Symptoms:** "Heap exhausted during allocation" errors, especially when processing `activities_streams` table.
**Solutions:**
1. **Increase system memory** or close other applications
3. **Reduce batch size** in the .load file:
```sql
change bellow to minor, default is 10
rows per range = 10
```
4. **Reduce workers** in the .load file:
```sql
workers = 1, concurrency = 1,
```
### PostgreSQL Connection Issues
**Symptoms:** Connection refused or authentication errors.
**Solutions:**
1. Verify PostgreSQL is running and accessible
2. Check password authentication method (use MD5, not SCRAM-SHA-256)
3. Verify `pg_hba.conf` allows connections from pgloader host
### Large JSON Data Issues
**Symptoms:** Errors processing `stream_waypoints` column in `activities_streams`.
**Solutions:**
1. The updated `transforms.lisp` includes `stream-waypoints-to-jsonb` function
2. Use split migration approach for better memory management
3. Consider manual cleanup of very large JSON records before migration
### Migration Time Estimates
- **Small databases** (< 1000 activities): 5-15 minutes
- **Medium databases** (1000-5000 activities): 15-60 minutes
- **Large databases** (> 5000 activities): 1+ hours
**Monitoring Progress:**
- Monitor the log file: `tail -f migration_*.log`
- Check PostgreSQL logs for any issues
- Monitor system memory usage during migration

View File

@@ -0,0 +1,27 @@
LOAD DATABASE
FROM mysql://endurain:password@mariadb-host:3306/endurain
INTO postgresql://endurain:password@postgres-host:5432/endurain
WITH include drop, create tables, create indexes, reset sequences,
workers = 1, concurrency = 1,
multiple readers per thread, rows per range = 1
INCLUDING ONLY TABLE NAMES MATCHING 'activities_streams'
SET PostgreSQL PARAMETERS
maintenance_work_mem to '1GB',
work_mem to '512MB'
SET MySQL PARAMETERS
net_read_timeout = '600',
net_write_timeout = '600'
CAST type json to jsonb
drop default drop not null,
column activities_streams.stream_waypoints to jsonb
using stream-waypoints-to-jsonb
BEFORE LOAD DO
$$ SET work_mem = '1GB'; $$,
$$ SET maintenance_work_mem = '1GB'; $$;

View File

@@ -0,0 +1,38 @@
LOAD DATABASE
FROM mysql://endurain:password@mariadb-host:3306/endurain
INTO postgresql://endurain:password@postgres-host:5432/endurain
WITH include drop, create tables, create indexes, reset sequences,
workers = 2, concurrency = 1,
multiple readers per thread, rows per range = 5000
EXCLUDING TABLE NAMES MATCHING 'activities_streams'
SET PostgreSQL PARAMETERS
maintenance_work_mem to '2GB',
work_mem to '512MB'
SET MySQL PARAMETERS
net_read_timeout = '300',
net_write_timeout = '300'
CAST type datetime to timestamptz
drop default drop not null using zero-dates-to-null,
type date to date
drop default drop not null using zero-dates-to-null,
type tinyint when (= 1 precision) to boolean drop typemod using tinyint-to-boolean,
type bit when (= 1 precision) to boolean drop typemod using bits-to-boolean2,
type json to jsonb
drop default drop not null
BEFORE LOAD DO
$$ DROP SCHEMA IF EXISTS public CASCADE; $$,
$$ CREATE SCHEMA public; $$,
$$ SET work_mem = '1GB'; $$
AFTER LOAD DO
$$ ALTER SCHEMA public OWNER TO endurain; $$;

View File

@@ -0,0 +1,559 @@
;;;
;;; Tools to handle data conversion to PostgreSQL format
;;;
;;; Any function that you want to use to transform data with will get looked
;;; up in the pgloader.transforms package, when using the default USING
;;; syntax for transformations.
(in-package :pgloader.transforms)
;;;
;;; This package is used to generate symbols in the CL code that
;;; project-fields produces, allowing to use symbols such as t. It's
;;; important that the user-symbols package doesn't :use cl.
;;;
(defpackage #:pgloader.user-symbols (:use))
(defun intern-symbol (symbol-name &optional (overrides '()))
"Return a symbol in either PGLOADER.TRANSFORMS if it exists there
already (it's a user provided function) or a PGLOADER.USER-SYMBOLS
package.
OVERRIDES is an alist of symbol . value, allowing called to force certain
values: the classic example is how to parse the \"nil\" symbol-name.
Given OVERRIDES as '((nil . nil)) the returned symbol will be cl:nil
rather than pgloader.user-symbols::nil."
(let ((overriden (assoc symbol-name overrides :test #'string-equal)))
(if overriden
(cdr overriden)
(multiple-value-bind (symbol status)
(find-symbol (string-upcase symbol-name)
(find-package "PGLOADER.TRANSFORMS"))
;; pgloader.transforms package (:use :cl) so we might find variable
;; names in there that we want to actually intern in
;; pgloader.user-symbols so that users may use e.g. t as a column name...
;; so only use transform symbol when it denotes a function
(cond
((and status (fboundp symbol)) symbol) ; a transform function
(t
(intern (string-upcase symbol-name)
(find-package "PGLOADER.USER-SYMBOLS"))))))))
;;;
;;; Handling typmod in the general case, don't apply to ENUM types
;;;
(defun parse-column-typemod (data-type column-type)
"Given int(7), returns the number 7.
Beware that some data-type are using a typmod looking definition for
things that are not typmods at all: enum."
(unless (or (string= "enum" data-type)
(string= "set" data-type))
(let ((start-1 (position #\( column-type)) ; just before start position
(end (position #\) column-type))) ; just before end position
(when (and start-1 (< (+ 1 start-1) end))
(destructuring-bind (a &optional b)
(mapcar #'parse-integer
(sq:split-sequence #\, column-type
:start (+ 1 start-1) :end end))
(list a b))))))
(defun typemod-expr-matches-p (rule-typemod-expr typemod)
"Check if an expression such as (< 10) matches given typemod."
(funcall (compile nil (typemod-expr-to-function rule-typemod-expr)) typemod))
(defun typemod-expr-to-function (expr)
"Transform given EXPR into a callable function object."
`(lambda (typemod)
(destructuring-bind (precision &optional (scale 0))
typemod
(declare (ignorable precision scale))
,expr)))
;;;
;;; Some optimisation stanza
;;;
(declaim (inline intern-symbol
zero-dates-to-null
date-with-no-separator
time-with-no-separator
tinyint-to-boolean
bits-to-boolean
bits-to-hex-bitstring
int-to-ip
ip-range
convert-mysql-point
integer-to-string
float-to-string
empty-string-to-null
set-to-enum-array
right-trim
byte-vector-to-bytea
sqlite-timestamp-to-timestamp
sql-server-uniqueidentifier-to-uuid
sql-server-bit-to-boolean
varbinary-to-string
base64-decode
hex-to-dec
byte-vector-to-hexstring
;; db3 specifics
logical-to-boolean
db3-trim-string
db3-numeric-to-pgsql-numeric
db3-numeric-to-pgsql-integer
db3-date-to-pgsql-date))
;;;
;;; Transformation functions
;;;
(defun zero-dates-to-null (date-string)
"MySQL accepts '0000-00-00' as a date, we want NIL (SQL NULL) instead."
(cond
((null date-string) nil)
((string= date-string "") nil)
;; day is 00
((string= date-string "0000-00-00" :start1 8 :end1 10 :start2 8 ) nil)
;; month is 00
((string= date-string "0000-00-00" :start1 5 :end1 7 :start2 5 :end2 7) nil)
;; year is 0000
((string= date-string "0000-00-00" :start1 0 :end1 4 :start2 0 :end2 4) nil)
(t date-string)))
(defun date-with-no-separator
(date-string
&optional (format '((:year 0 4)
(:month 4 6)
(:day 6 8)
(:hour 8 10)
(:minute 10 12)
(:seconds 12 14))))
"Apply this function when input date in like '20041002152952'"
;; only process non-zero dates
(declare (type (or null string) date-string))
(let ((str-length (length date-string))
(expected-length (reduce #'max (mapcar #'third format))))
(cond ((null date-string) nil)
((string= date-string "") nil)
((not (= expected-length str-length)) nil)
(t
(destructuring-bind (&key year month day hour minute seconds
&allow-other-keys)
(loop
for (name start end) in format
append (list name (subseq date-string start end)))
(if (or (string= year "0000")
(string= month "00")
(string= day "00"))
nil
(format nil "~a-~a-~a ~a:~a:~a"
year month day hour minute seconds)))))))
(defun time-with-no-separator
(time-string
&optional (format '((:hour 0 2)
(:minute 2 4)
(:seconds 4 6)
(:msecs 6 nil))))
"Apply this function when input date in like '08231560'"
(declare (type (or null string) time-string))
(when time-string
(destructuring-bind (&key hour minute seconds msecs
&allow-other-keys)
(loop
for (name start end) in format
append (list name (subseq time-string start end)))
(format nil "~a:~a:~a.~a" hour minute seconds msecs))))
(defun tinyint-to-boolean (integer-string)
"When using MySQL, strange things will happen, like encoding booleans into
tinyiny that are either 0 (false) or 1 (true). Of course PostgreSQL wants
'f' and 't', respectively."
(when integer-string
(if (string= "0" integer-string) "f" "t")))
(defun bits-to-boolean (bit-vector)
"When using MySQL, strange things will happen, like encoding booleans into
bit(1). Of course PostgreSQL wants 'f' and 't'."
(when bit-vector
(handler-case
(when (and (arrayp bit-vector) (= 1 (length bit-vector)))
(let ((bit (aref bit-vector 0)))
;; we might have either a char or a number here, see issue #684.
;; current guess when writing the code is that it depends on MySQL
;; version, but this has not been checked.
(etypecase bit
(fixnum (if (= 0 bit) "f" "t"))
(character (if (= 0 (char-code bit)) "f" "t")))))
(error () nil))))
(defun bits-to-boolean2 (bit-vector)
"When using MySQL, strange things will happen, like encoding booleans into
bit(1). Of course PostgreSQL wants 'f' and 't'."
(when bit-vector
(cond
((null bit-vector) nil)
((and (stringp bit-vector) (= 4 (length bit-vector)))
(if (string= "b'0'" bit-vector) "f" "t"))
((and (arrayp bit-vector) (= 1 (length bit-vector)))
(if (= 0 (aref bit-vector 0)) "f" "t"))
(t nil))))
(defun bits-to-hex-bitstring (bit-vector-or-string)
"Transform bit(XX) from MySQL to bit(XX) in PostgreSQL."
(etypecase bit-vector-or-string
(null nil)
;; default value as string looks like "b'0'", skip b' and then closing '
(string (let ((default bit-vector-or-string)
(size (length bit-vector-or-string)))
(subseq default 2 (+ -1 size))))
(array (let* ((bytes bit-vector-or-string)
(size (length bit-vector-or-string))
(digits "0123456789abcdef")
(hexstr
(make-array (+ 1 (* size 2)) :element-type 'character)))
;; use Postgres hex bitstring support: x0ff
(setf (aref hexstr 0) #\X)
(loop :for pos :from 1 :by 2
:for byte :across bytes
:do (let ((high (ldb (byte 4 4) byte))
(low (ldb (byte 4 0) byte)))
(setf (aref hexstr pos) (aref digits high))
(setf (aref hexstr (+ pos 1)) (aref digits low))))
hexstr))))
(defun int-to-ip (int)
"Transform an IP as integer into its dotted notation, optimised code from
stassats."
(declare (optimize speed)
(type (unsigned-byte 32) int))
(let ((table (load-time-value
(let ((vec (make-array (+ 1 #xFFFF))))
(loop for i to #xFFFF
do (setf (aref vec i)
(coerce (format nil "~a.~a"
(ldb (byte 8 8) i)
(ldb (byte 8 0) i))
'simple-base-string)))
vec)
t)))
(declare (type (simple-array simple-base-string (*)) table))
(concatenate 'simple-base-string
(aref table (ldb (byte 16 16) int))
"."
(aref table (ldb (byte 16 0) int)))))
(defun ip-range (start-integer-string end-integer-string)
"Transform a couple of integers to an IP4R ip range notation."
(declare (optimize speed)
(type (or null string) start-integer-string end-integer-string))
(when (and start-integer-string end-integer-string)
(let ((ip-start (int-to-ip (parse-integer start-integer-string)))
(ip-end (int-to-ip (parse-integer end-integer-string))))
(concatenate 'simple-base-string ip-start "-" ip-end))))
(defun convert-mysql-point (mysql-point-as-string)
"Transform the MYSQL-POINT-AS-STRING into a suitable representation for
PostgreSQL.
Input: \"POINT(48.5513589 7.6926827)\" ; that's using astext(column)
Output: (48.5513589,7.6926827)"
(when mysql-point-as-string
(let* ((point (subseq mysql-point-as-string 5)))
(setf (aref point (position #\Space point)) #\,)
point)))
(defun convert-mysql-linestring (mysql-linestring-as-string)
"Transform the MYSQL-POINT-AS-STRING into a suitable representation for
PostgreSQL.
Input: \"LINESTRING(-87.87342467651445 45.79684462673078,-87.87170806274479 45.802110434248966)\" ; that's using astext(column)
Output: [(-87.87342467651445,45.79684462673078),(-87.87170806274479,45.802110434248966)]"
(when mysql-linestring-as-string
(let* ((data (subseq mysql-linestring-as-string
11
(- (length mysql-linestring-as-string) 1))))
(with-output-to-string (s)
(write-string "[" s)
(loop :for first := t :then nil
:for point :in (split-sequence:split-sequence #\, data)
:for (x y) := (split-sequence:split-sequence #\Space point)
:do (format s "~:[,~;~](~a,~a)" first x y))
(write-string "]" s)))))
(defun integer-to-string (integer-string)
"Transform INTEGER-STRING parameter into a proper string representation of
it. In particular be careful of quoted-integers, thanks to SQLite default
values."
(declare (type (or null string fixnum) integer-string))
(when integer-string
(princ-to-string
(typecase integer-string
(integer integer-string)
(string (handler-case
(parse-integer integer-string :start 0)
(condition (c)
(declare (ignore c))
(parse-integer integer-string :start 1
:end (- (length integer-string) 1)))))))))
(defun float-to-string (float)
"Transform a Common Lisp float value into its string representation as
accepted by PostgreSQL, that is 100.0 rather than 100.0d0."
(declare (type (or null fixnum float string) float))
(when float
(typecase float
(double-float (let ((*read-default-float-format* 'double-float))
(princ-to-string float)))
(string float)
(t (princ-to-string float)))))
(defun set-to-enum-array (set-string)
"Transform a MySQL SET value into a PostgreSQL ENUM Array"
(when set-string
(format nil "{~a}" set-string)))
(defun empty-string-to-null (string)
"MySQL ENUM sometimes return an empty string rather than a NULL."
(when string
(if (string= string "") nil string)))
(defun right-trim (string)
"Remove whitespaces at end of STRING."
(declare (type (or null simple-string) string))
(when string
(string-right-trim '(#\Space) string)))
(defun remove-null-characters (string)
"Remove NULL-characters (0x00) from STRING"
(when string
(remove #\Nul string)))
(defun byte-vector-to-bytea (vector)
"Transform a simple array of unsigned bytes to the PostgreSQL bytea
representation as documented at
http://www.postgresql.org/docs/9.3/interactive/datatype-binary.html
Note that we choose here the bytea Hex Format."
(declare (type (or null string (simple-array (unsigned-byte 8) (*))) vector))
(etypecase vector
(null nil)
(string (if (string= "" vector)
nil
(error "byte-vector-to-bytea called on a string: ~s" vector)))
(simple-array
(let ((hex-digits "0123456789abcdef")
(bytea (make-array (+ 2 (* 2 (length vector)))
:initial-element #\0
:element-type 'standard-char)))
;; The entire string is preceded by the sequence \x (to distinguish it
;; from the escape format).
(setf (aref bytea 0) #\\)
(setf (aref bytea 1) #\x)
(loop for pos from 2 by 2
for byte across vector
do (let ((high (ldb (byte 4 4) byte))
(low (ldb (byte 4 0) byte)))
(setf (aref bytea pos) (aref hex-digits high))
(setf (aref bytea (+ pos 1)) (aref hex-digits low)))
finally (return bytea))))))
(defun ensure-parse-integer (string-or-integer)
"Return an integer value if string-or-integer is an integer or a string
containing only an integer value, in all other cases return nil."
(typecase string-or-integer
(string (multiple-value-bind (integer position)
(parse-integer string-or-integer :junk-allowed t)
(when (= (length string-or-integer) position)
integer)))
(integer string-or-integer)))
(defun sqlite-timestamp-to-timestamp (date-string-or-integer)
(declare (type (or null integer simple-string) date-string-or-integer))
(when date-string-or-integer
(cond ((and (typep date-string-or-integer 'integer)
(= 0 date-string-or-integer))
nil)
((typep date-string-or-integer 'integer)
;; a non-zero integer is a year
(format nil "~a-01-01" date-string-or-integer))
((stringp date-string-or-integer)
;; default values are sent as strings
(let ((maybe-integer (ensure-parse-integer date-string-or-integer)))
(cond ((and maybe-integer (= 0 maybe-integer))
nil)
(maybe-integer
(format nil "~a-01-01" maybe-integer))
(t
date-string-or-integer)))))))
;;;
;;; MS SQL Server GUID binary representation is a mix of endianness, as
;;; documented at
;;; https://dba.stackexchange.com/questions/121869/sql-server-uniqueidentifier-guid-internal-representation
;;; and
;;; https://en.wikipedia.org/wiki/Globally_unique_identifier#Binary_encoding.
;;;
;;; "Other systems, notably Microsoft's marshalling of UUIDs in their
;;; COM/OLE libraries, use a mixed-endian format, whereby the first three
;;; components of the UUID are little-endian, and the last two are
;;; big-endian."
;;;
;;; So here we steal some code from the UUID lib and make it compatible with
;;; this strange mix of endianness for SQL Server.
;;;
(defmacro arr-to-bytes-rev (from to array)
"Helper macro used in byte-array-to-uuid."
`(loop for i from ,to downto ,from
with res = 0
do (setf (ldb (byte 8 (* 8 (- i ,from))) res) (aref ,array i))
finally (return res)))
(defun sql-server-uniqueidentifier-to-uuid (id)
(declare (type (or null (array (unsigned-byte 8) (16))) id))
(when id
(let ((uuid
(make-instance 'uuid:uuid
:time-low (arr-to-bytes-rev 0 3 id)
:time-mid (arr-to-bytes-rev 4 5 id)
:time-high (arr-to-bytes-rev 6 7 id)
:clock-seq-var (aref id 8)
:clock-seq-low (aref id 9)
:node (uuid::arr-to-bytes 10 15 id))))
(princ-to-string uuid))))
(defun unix-timestamp-to-timestamptz (unixtime-string)
"Takes a unix timestamp (seconds since beginning of 1970) and converts it
into a string of format \"YYYY-MM-DD hh:mm:ssZ\".
Assumes that the unix timestamp is in UTC time."
(when unixtime-string
(let ((unixtime (ensure-parse-integer unixtime-string))
;; Universal time uses a different epoch than unix time
(unix-universal-diff (load-time-value
(encode-universal-time 0 0 0 1 1 1970 0))))
(multiple-value-bind
(second minute hour date month year)
(decode-universal-time (+ unixtime unix-universal-diff) 0)
(format nil
"~d-~2,'0d-~2,'0d ~2,'0d:~2,'0d:~2,'0dZ"
year month date hour minute second)))))
(defun sql-server-bit-to-boolean (bit-string-or-integer)
"We might receive bits as '((0))'"
(typecase bit-string-or-integer
(integer (if (= 0 bit-string-or-integer) "f" "t"))
(string
(cond ((string= "0" bit-string-or-integer) "f")
((string= "1" bit-string-or-integer) "t")
((string= "((0))" bit-string-or-integer) "f")
((string= "((1))" bit-string-or-integer) "t")
(t nil)))))
(defun byte-vector-to-hexstring (vector)
"Transform binary input received as a vector of bytes into a string of
hexadecimal digits, as per the following example:
Input: #(136 194 152 47 66 138 70 183 183 27 33 6 24 174 22 88)
Output: 88C2982F428A46B7B71B210618AE1658"
(declare (type (or null string (simple-array (unsigned-byte 8) (*))) vector))
(etypecase vector
(null nil)
(string (if (string= "" vector)
nil
(error "byte-vector-to-bytea called on a string: ~s" vector)))
(simple-array
(let ((hex-digits "0123456789abcdef")
(bytea (make-array (* 2 (length vector))
:initial-element #\0
:element-type 'standard-char)))
(loop for pos from 0 by 2
for byte across vector
do (let ((high (ldb (byte 4 4) byte))
(low (ldb (byte 4 0) byte)))
(setf (aref bytea pos) (aref hex-digits high))
(setf (aref bytea (+ pos 1)) (aref hex-digits low)))
finally (return bytea))))))
(defun varbinary-to-string (string)
(let ((babel::*default-character-encoding*
(or qmynd::*mysql-encoding*
babel::*default-character-encoding*)))
(etypecase string
(null nil)
(string string)
(vector (babel:octets-to-string string)))))
(defun base64-decode (string)
(etypecase string
(null nil)
(string (base64:base64-string-to-string string))))
(defun hex-to-dec (hex-string)
(etypecase hex-string
(null nil)
(integer hex-string)
(string (write-to-string (parse-integer hex-string :radix 16)))))
;;;
;;; JSON transformation functions for activities_streams
;;;
(defun stream-waypoints-to-jsonb (json-string)
"Transform MySQL JSON string to PostgreSQL JSONB format for stream_waypoints column."
(when json-string
(etypecase json-string
(null nil)
(string
(if (string= "" json-string)
nil
json-string))
(t (write-to-string json-string)))))
;;;
;;; DBF/DB3 transformation functions
;;;
(defun logical-to-boolean (value)
"Convert a DB3 logical value to a PostgreSQL boolean."
(if (member value '("?" " ") :test #'string=) nil value))
(defun db3-trim-string (value)
"DB3 Strings a right padded with spaces, fix that."
(string-right-trim '(#\Space) value))
(defun db3-numeric-to-pgsql-numeric (value)
"DB3 numerics should be good to go, but might contain spaces."
(let ((trimmed-string (string-trim '(#\Space) value)))
(unless (string= "" trimmed-string)
trimmed-string)))
(defun db3-numeric-to-pgsql-integer (value)
"DB3 numerics should be good to go, but might contain spaces."
(etypecase value
(null nil)
(integer (write-to-string value))
(string (let ((integer-or-nil (parse-integer value :junk-allowed t)))
(when integer-or-nil
(write-to-string integer-or-nil))))))
(defun db3-date-to-pgsql-date (value)
"Convert a DB3 date to a PostgreSQL date."
(when (and value (string/= "" value) (= 8 (length value)))
(let ((year (parse-integer (subseq value 0 4) :junk-allowed t))
(month (parse-integer (subseq value 4 6) :junk-allowed t))
(day (parse-integer (subseq value 6 8) :junk-allowed t)))
(when (and year month day)
(format nil "~4,'0d-~2,'0d-~2,'0d" year month day)))))

View File

@@ -9,6 +9,7 @@ nav:
- Hosting Guide:
- Getting started easy: getting-started/getting-started.md
- Getting started advanced: getting-started/advanced-started.md
- MariaDB to Postgres migration: getting-started/maria-to-postgres-migration.md
- Integrations:
- 3rd party apps: integrations/3rd-party-apps.md
- 3rd party services: integrations/3rd-party-services.md