Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Better support my sql5.5 #52

Open
wants to merge 4 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Jump to
Jump to file
Failed to load files.
Diff view
Diff view
43 changes: 42 additions & 1 deletion migration/FromMySqlToPostgreSql/FromMySqlToPostgreSql.php
Expand Up @@ -32,6 +32,13 @@ class FromMySqlToPostgreSql
*/
private $mysql;

/**
* A String to hold database version.
*
* @var string
*/
private $mysqlVersion;

/**
* A \PDO instance, connected to PostgreSql server.
*
Expand Down Expand Up @@ -366,6 +373,32 @@ private function generateError(\PDOException $e, $strMessage, $strSql = '')
unset($strError);
}

/**
* Retrieve MySQL version
*
* @param void
* @return bool
*/
private function retrieveMySqlVersion()
{
$sql = '';

try {
$this->connect();
$sql = 'SELECT VERSION() AS mysql_version;';
$stmt = $this->mysql->query($sql);
$arrRows = $stmt->fetchAll(\PDO::FETCH_ASSOC);
$this->mysqlVersion = $arrRows[0]['mysql_version'];
unset( $sql, $stmt, $arrResult );
} catch (\PDOException $e) {
$this->generateError(
$e,
__METHOD__ . PHP_EOL . "\t" . '-- Cannot retrieve version from source (MySql) database...',
$sql
);
}
}

/**
* Load MySql tables, that need to be migrated into an array.
*
Expand Down Expand Up @@ -679,7 +712,12 @@ private function arrangeColumnsData(array $arrColumns)
|| stripos($arrColumn['Type'], 'linestring') !== false
|| stripos($arrColumn['Type'], 'polygon') !== false
) {
$strRetVal .= 'HEX(ST_AsWKB(`' . $arrColumn['Field'] . '`)),';
if ( substr( $this->mysqlVersion, 0, 3 ) <= 5.5
) {
$strRetVal .= 'HEX(AsWKB(`' . $arrColumn['Field'] . '`)),';
} else {
$strRetVal .= 'HEX(ST_AsWKB(`' . $arrColumn['Field'] . '`)),';
}
} elseif (
stripos($arrColumn['Type'], 'blob') !== false
|| stripos($arrColumn['Type'], 'binary') !== false
Expand Down Expand Up @@ -1527,6 +1565,9 @@ public function migrate()
PHP_EOL
);

$this->retrieveMySqlVersion();
$this->log('-- Discovered MySQL Version "' . $this->mysqlVersion . '"' . PHP_EOL);

ini_set('memory_limit', '-1');

/*
Expand Down
2 changes: 1 addition & 1 deletion migration/FromMySqlToPostgreSql/MapDataTypes.php
Expand Up @@ -164,7 +164,7 @@ private function __construct()

'point' => [
'increased_size' => '',
Copy link
Owner

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Why?

While geometry is capable to hold point value, the
point simply restrict a value to a specific type...

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Here is what I know: when I use this script, it fails on all of my point data types ( contain latitude and longitude). This change allows my data to import.

Here is what I have learned:
postgresql point storage size is only 16 byte
postgis geometry point storage size is 29 byte

Here is what I am guessing:
the postgresql point is simply an xy coordinate
the postgis geometry point is an xy coordinate plus Spatial Reference System attached to it.

As this post points out - you can not convert from one to the other.
http://dba.stackexchange.com/questions/156947/how-do-i-go-from-a-postgresql-native-point-type-to-a-postgis-point/156948

I don't claim to be a PostgreSQL expert. If there is another way to make this import work I would like to know. I can provide a MySQL test case if that would help.

Copy link
Owner

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

The test-case would be appreciated...
Thanks!

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

MySQL test case:

create table testGeoPoint (
ID bigint(20) NOT NULL,
GEOPOINT point DEFAULT NULL,
LATITUDE decimal(19,10) DEFAULT NULL,
LONGITUDE decimal(19,10) DEFAULT NULL
) ENGINE=InnoDB;

insert into testGeoPoint values ( 1, GeomFromText('POINT(-74.0445000000 40.6892000000 )' ), 40.6892000000, -74.0445000000 );

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Error output I see is:
--Following MySQL query will return a data set, rejected by PostgreSQL:
SELECT ID,HEX(AsWKB(GEOPOINT)),LATITUDE,LONGITUDE FROM testGeoPoint LIMIT 0, 1;

    -- FromMySqlToPostgreSql::populateTableWorker

    -- PDOException code: 22P02
    -- File: /home/mores/wip/MySQL2PSQL/php/migration/FromMySqlToPostgreSql/FromMySqlToPostgreSql.php
    -- Line: 674
    -- Message: SQLSTATE[22P02]: Invalid text representation: 7 ERROR:  invalid input syntax for type point: "0101000000022B8716D98252C09C33A2B437584440"

CONTEXT: COPY testGeoPoint, line 1, column GEOPOINT: "0101000000022B8716D98252C09C33A2B437584440"
-- SQL: SELECT ID,HEX(AsWKB(GEOPOINT)),LATITUDE,LONGITUDE FROM testGeoPoint LIMIT 0, 1;
COPY "test"."testGeoPoint" FROM '/home/mores/wip/MySQL2PSQL/php/temporary_directory/testGeoPoint0.csv' DELIMITER ',' CSV;

    -------------------------------------------------------

'type' => 'point',
'type' => 'geometry',
'mySqlVarLenPgSqlFixedLen' => false,
],

Expand Down