mirror of
				https://gitlab.com/Chill-Projet/chill-bundles.git
				synced 2025-10-31 01:08:26 +00:00 
			
		
		
		
	
		
			
				
	
	
		
			71 lines
		
	
	
		
			3.4 KiB
		
	
	
	
		
			PHP
		
	
	
	
	
	
			
		
		
	
	
			71 lines
		
	
	
		
			3.4 KiB
		
	
	
	
		
			PHP
		
	
	
	
	
	
| <?php
 | |
| 
 | |
| declare(strict_types=1);
 | |
| 
 | |
| namespace Chill\Migrations\Person;
 | |
| 
 | |
| use Doctrine\DBAL\Schema\Schema;
 | |
| use Doctrine\Migrations\AbstractMigration;
 | |
| 
 | |
| /**
 | |
|  * Change model relation between Person and AccompagnyingPeriod
 | |
|  * Migrate datas into new join table
 | |
|  *
 | |
|  * @author Mathieu Jaumotte mathieu.jaumotte@champs-libres.coop
 | |
|  */
 | |
| final class Version20210326113045 extends AbstractMigration
 | |
| {
 | |
|     private $datas = [];
 | |
|     
 | |
|     public function getDescription() : string
 | |
|     {
 | |
|         return 'Change model relation between Person and AccompagnyingPeriod, without losing datas when going up';
 | |
|     }
 | |
|     
 | |
|     /**
 | |
|      *  In these direction, there is no loss.
 | |
|      */
 | |
|     public function up(Schema $schema) : void
 | |
|     {
 | |
|         // create join table
 | |
|         $this->addSql('CREATE TABLE persons_accompanying_periods (person_id INT NOT NULL, accompanyingperiod_id INT NOT NULL, PRIMARY KEY(person_id, accompanyingperiod_id))');
 | |
|         $this->addSql('CREATE INDEX IDX_49A3871F217BBB47 ON persons_accompanying_periods (person_id)');
 | |
|         $this->addSql('CREATE INDEX IDX_49A3871F550B0C53 ON persons_accompanying_periods (accompanyingperiod_id)');
 | |
|         $this->addSql('ALTER TABLE persons_accompanying_periods ADD CONSTRAINT FK_49A3871F217BBB47 FOREIGN KEY (person_id) REFERENCES chill_person_person (id) ON DELETE CASCADE NOT DEFERRABLE INITIALLY IMMEDIATE');
 | |
|         $this->addSql('ALTER TABLE persons_accompanying_periods ADD CONSTRAINT FK_49A3871F550B0C53 FOREIGN KEY (accompanyingperiod_id) REFERENCES chill_person_accompanying_period (id) ON DELETE CASCADE NOT DEFERRABLE INITIALLY IMMEDIATE');
 | |
|     
 | |
|         // insert datas in new join table
 | |
|         $this->addSql('INSERT INTO persons_accompanying_periods (person_id, accompanyingperiod_id) '
 | |
|             . 'SELECT person_id, id as accompagnying_period_id FROM chill_person_accompanying_period WHERE person_id IS NOT NULL');
 | |
|         
 | |
|         // drop column
 | |
|         $this->addSql('DROP INDEX idx_64a4a621217bbb47');
 | |
|         $this->addSql('ALTER TABLE chill_person_accompanying_period DROP CONSTRAINT fk_64a4a621217bbb47');
 | |
|         $this->addSql('ALTER TABLE chill_person_accompanying_period DROP person_id');
 | |
|     }
 | |
|     
 | |
|     /**
 | |
|      *  The distinct clause makes that for each group of duplicates, it keeps only the first row in the returned result set.
 | |
|      *  Then we have only few lost datas. Lost datas: when many persons for one AccompanyingPeriod (keep only first person)
 | |
|      */
 | |
|     public function down(Schema $schema) : void
 | |
|     {
 | |
|         // add column
 | |
|         $this->addSql('ALTER TABLE chill_person_accompanying_period ADD person_id INT DEFAULT NULL');
 | |
|         $this->addSql('ALTER TABLE chill_person_accompanying_period ADD CONSTRAINT fk_64a4a621217bbb47 FOREIGN KEY (person_id) REFERENCES chill_person_person (id) NOT DEFERRABLE INITIALLY IMMEDIATE');
 | |
|         $this->addSql('CREATE INDEX idx_64a4a621217bbb47 ON chill_person_accompanying_period (person_id)');
 | |
| 
 | |
|         // insert datas in existing table
 | |
|         $this->addSql('UPDATE chill_person_accompanying_period AS ap '
 | |
|             . 'SET person_id = jt.person_id '
 | |
|             . 'FROM ( '
 | |
|             .   'SELECT DISTINCT ON (accompanyingperiod_id) accompanyingperiod_id AS id, person_id FROM persons_accompanying_periods '
 | |
|             .   'ORDER BY id, person_id ASC '
 | |
|             . ') AS jt '
 | |
|             . 'WHERE ap.id = jt.id');
 | |
|         
 | |
|         // drop join table
 | |
|         $this->addSql('DROP TABLE persons_accompanying_periods');
 | |
|     }
 | |
| }
 |