#86: Automatic MySQL to PostgreSQL import

This commit is contained in:
Josef Citrine 2016-07-14 23:26:11 +01:00
parent 4c6aeb1a6e
commit 06afc0c9d7
2 changed files with 111 additions and 0 deletions

38
database/after-import.sql Normal file
View file

@ -0,0 +1,38 @@
ALTER TABLE users ALTER created_at TYPE timestamp(0) without time zone, ALTER updated_at TYPE timestamp(0) without time zone, ALTER bio SET DEFAULT '';
ALTER TABLE tracks ALTER created_at TYPE timestamp(0) without time zone,
ALTER updated_at TYPE timestamp(0) without time zone,
ALTER deleted_at TYPE timestamp(0) without time zone,
ALTER published_at TYPE timestamp(0) without time zone,
ALTER released_at TYPE timestamp(0) without time zone,
ALTER license_id DROP NOT NULL,
ALTER genre_id DROP NOT NULL,
ALTER track_type_id DROP NOT NULL,
ALTER description DROP NOT NULL,
ALTER lyrics DROP NOT NULL,
ALTER cover_id DROP NOT NULL,
ALTER album_id DROP NOT NULL,
ALTER track_number DROP NOT NULL,
ALTER hash DROP NOT NULL,
ALTER metadata DROP NOT NULL,
ALTER original_tags DROP NOT NULL,
ALTER is_vocal SET DEFAULT false,
ALTER is_explicit SET DEFAULT false,
ALTER is_downloadable SET DEFAULT false,
ALTER view_count SET DEFAULT 0,
ALTER play_count SET DEFAULT 0,
ALTER download_count SET DEFAULT 0,
ALTER favourite_count SET DEFAULT 0,
ALTER comment_count SET DEFAULT 0,
ALTER is_latest SET DEFAULT false,
ALTER is_listed SET DEFAULT true;
ALTER TABLE track_files ALTER created_at TYPE timestamp(0) without time zone, ALTER updated_at TYPE timestamp(0) without time zone;
ALTER TABLE images ALTER created_at TYPE timestamp(0) without time zone, ALTER updated_at TYPE timestamp(0) without time zone;
ALTER TABLE genres ALTER created_at TYPE timestamp(0) without time zone, ALTER updated_at TYPE timestamp(0) without time zone;
ALTER TABLE resource_users ALTER is_followed SET DEFAULT false, ALTER is_favourited SET DEFAULT false, ALTER is_pinned SET DEFAULT false, ALTER view_count SET DEFAULT 0, ALTER play_count SET DEFAULT 0, ALTER download_count SET DEFAULT 0;
ALTER TABLE comments ALTER ip_address DROP NOT NULL, ALTER profile_id DROP NOT NULL, ALTER track_id DROP NOT NULL, ALTER album_id DROP NOT NULL, ALTER playlist_id DROP NOT NULL, ALTER created_at TYPE timestamp(0) without time zone, ALTER updated_at TYPE timestamp(0) without time zone, ALTER deleted_at TYPE timestamp(0) without time zone;
ALTER TABLE playlists ALTER created_at TYPE timestamp(0) without time zone, ALTER updated_at TYPE timestamp(0) without time zone, ALTER deleted_at TYPE timestamp(0) without time zone, ALTER track_count SET DEFAULT 0, ALTER view_count SET DEFAULT 0, ALTER download_count SET DEFAULT 0, ALTER favourite_count SET DEFAULT 0, ALTER follow_count SET DEFAULT 0, ALTER comment_count SET DEFAULT 0;
ALTER TABLE playlist_track ALTER created_at TYPE timestamp(0) without time zone, ALTER updated_at TYPE timestamp(0) without time zone;
ALTER TABLE albums ALTER created_at TYPE timestamp(0) without time zone, ALTER updated_at TYPE timestamp(0) without time zone, ALTER deleted_at TYPE timestamp(0) without time zone;
ALTER TABLE show_songs ALTER created_at TYPE timestamp(0) without time zone, ALTER updated_at TYPE timestamp(0) without time zone, ALTER deleted_at TYPE timestamp(0) without time zone;

View file

@ -0,0 +1,73 @@
<?php
use Illuminate\Database\Schema\Blueprint;
use Illuminate\Database\Migrations\Migration;
use Symfony\Component\Console\Output\ConsoleOutput;
class MysqlToPostgres extends Migration
{
private $console;
/**
* Run the migrations.
*
* @return void
*/
public function up()
{
$this->console = new ConsoleOutput();
// Generate pgloader config
$mysqlConnection = "from mysql://" . env('DB_USERNAME') . ":" . env('DB_PASSWORD') . "@" . env('DB_HOST') . "/" . env('DB_DATABASE');
$postgresConnection = "into postgresql://" . env('POSTGRESQL_DB_USERNAME', 'homestead') . ":" . env('POSTGRESQL_DB_PASSWORD', 'secret') . "@" . env('POSTGRESQL_DB_HOST', 'localhost') . "/" . env('POSTGRESQL_DB_DATABASE', 'homestead');
$header = "LOAD DATABASE";
$body = <<<'EOD'
with truncate
CAST type datetime to timestamp drop default drop not null using zero-dates-to-null,
type date drop not null drop default using zero-dates-to-null
EXCLUDING TABLE NAMES MATCHING 'migrations';
EOD;
$output = implode("\n", array($header, $mysqlConnection, $postgresConnection, $body));
$configPath = base_path() . "/pfmimport.load";
file_put_contents($configPath, $output);
// Run pgloader
$this->execRunWithCallback("pgloader " . $configPath);
// Run after-import.sql
DB::unprepared(file_get_contents(base_path() . "/database/after-import.sql"));
// Remove pgloader config
unlink($configPath);
}
private function execRunWithCallback($command)
{
$array = array();
exec($command, $array);
if (!empty($array)) {
foreach ($array as $line) {
$this->execCallback($line);
}
}
}
private function execCallback($line) {
$this->console->writeln("[PGLOADER] " . $line);
}
/**
* Reverse the migrations.
*
* @return void
*/
public function down()
{
//
}
}