From 2df1ea48af769cff2615c01804e29fbca5857039 Mon Sep 17 00:00:00 2001 From: Tomasz Narloch Date: Fri, 16 Feb 2018 02:06:41 +0100 Subject: [PATCH 1/4] Repair the update of database schema changes on postgreSQL --- .../sql/updates/postgresql/3.1.0.sql | 2 +- .../ChangeItem/PostgresqlChangeItem.php | 178 +++++++++++++----- 2 files changed, 133 insertions(+), 47 deletions(-) diff --git a/administrator/components/com_admin/sql/updates/postgresql/3.1.0.sql b/administrator/components/com_admin/sql/updates/postgresql/3.1.0.sql index 1893538b9d3b9..8b3b4974ad65a 100644 --- a/administrator/components/com_admin/sql/updates/postgresql/3.1.0.sql +++ b/administrator/components/com_admin/sql/updates/postgresql/3.1.0.sql @@ -1,6 +1,6 @@ /* Changes to tables where data type conflicts exist with MySQL (mainly dealing with null values */ ALTER TABLE "#__modules" ALTER COLUMN "content" SET DEFAULT ''; -ALTER TABLE "#__updates" ALTER COLUMN "data" SET DEFAULT ''; +--ALTER TABLE "#__updates" ALTER COLUMN "data" SET DEFAULT ''; /* Tags database schema */ diff --git a/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php b/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php index 14be04f90974b..f6a01791a2ab1 100644 --- a/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php +++ b/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php @@ -40,20 +40,28 @@ protected function buildCheckQuery() { // Initialize fields in case we can't create a check query $this->checkStatus = -1; // change status to skipped + $result = null; + $splitIntoWords = "~'[^']*'(*SKIP)(*F)|\s+~"; + $splitIntoActions = "~'[^']*'(*SKIP)(*F)|,~"; // Remove any newlines $this->updateQuery = str_replace("\n", '', $this->updateQuery); + // Remove trailing whitespace and semicolon + $this->updateQuery = rtrim($this->updateQuery, "; \t\n\r\0\x0B"); + // Fix up extra spaces around () and in general $find = array('#((\s*)\(\s*([^)\s]+)\s*)(\))#', '#(\s)(\s*)#'); $replace = array('($3)', '$1'); $updateQuery = preg_replace($find, $replace, $this->updateQuery); - $wordArray = explode(' ', $updateQuery); + $wordArray = preg_split($splitIntoWords, $updateQuery, null, PREG_SPLIT_NO_EMPTY); + + $totalWords = count($wordArray); // First, make sure we have an array of at least 6 elements // if not, we can't make a check query for this one - if (count($wordArray) < 6) + if ($totalWords < 6) { // Done with method return; @@ -64,93 +72,171 @@ protected function buildCheckQuery() if ($command === 'ALTER TABLE') { + // Check only the last action + $actions = ltrim(substr($updateQuery, strpos($updateQuery, $wordArray[2]) + strlen($wordArray[2]))); + $actions = preg_split($splitIntoActions, $actions); + + // Get the last action + $lastActionArray = preg_split($splitIntoWords, end($actions), null, PREG_SPLIT_NO_EMPTY); + + // Replace all actions by the last one + array_splice($wordArray, 3, count($wordArray), $lastActionArray); + + $totalWords = count($wordArray); + $alterCommand = strtoupper($wordArray[3] . ' ' . $wordArray[4]); if ($alterCommand === 'ADD COLUMN') { - $result = 'SELECT column_name FROM information_schema.columns WHERE table_name=' - . $this->fixQuote($wordArray[2]) . ' AND column_name=' . $this->fixQuote($wordArray[5]); + $result = 'SELECT column_name' + . ' FROM information_schema.columns' + . ' WHERE table_name=' + . $this->fixQuote($wordArray[2]) + . ' AND column_name=' . $this->fixQuote($wordArray[5]); $this->queryType = 'ADD_COLUMN'; - $this->msgElements = array($this->fixQuote($wordArray[2]), $this->fixQuote($wordArray[5])); + $this->msgElements = array( + $this->fixQuote($wordArray[2]), + $this->fixQuote($wordArray[5]) + ); } elseif ($alterCommand === 'DROP COLUMN') { - $result = 'SELECT column_name FROM information_schema.columns WHERE table_name=' - . $this->fixQuote($wordArray[2]) . ' AND column_name=' . $this->fixQuote($wordArray[5]); + $result = 'SELECT column_name' + . ' FROM information_schema.columns' + . ' WHERE table_name=' + . $this->fixQuote($wordArray[2]) + . ' AND column_name=' . $this->fixQuote($wordArray[5]); $this->queryType = 'DROP_COLUMN'; $this->checkQueryExpected = 0; - $this->msgElements = array($this->fixQuote($wordArray[2]), $this->fixQuote($wordArray[5])); + $this->msgElements = array( + $this->fixQuote($wordArray[2]), + $this->fixQuote($wordArray[5]) + ); } elseif ($alterCommand === 'ALTER COLUMN') { - if (strtoupper($wordArray[6]) === 'TYPE') + $alterAction = strtoupper($wordArray[6]); + + if ($alterAction === 'TYPE') { $type = ''; - for ($i = 7, $iMax = count($wordArray); $i < $iMax; $i++) + for ($i = 7; $i < $totalWords; $i++) { $type .= $wordArray[$i] . ' '; } - if ($pos = strpos($type, '(')) + if ($pos = stripos($type, 'USING')) { $type = substr($type, 0, $pos); } - if ($pos = strpos($type, ';')) + if ($pos = strpos($type, '(')) { - $type = substr($type, 0, $pos); + $datatype = substr($type, 0, $pos); + } + else + { + $datatype = substr($type, 0, -1); } - $result = 'SELECT column_name, data_type FROM information_schema.columns WHERE table_name=' - . $this->fixQuote($wordArray[2]) . ' AND column_name=' . $this->fixQuote($wordArray[5]) - . ' AND data_type=' . $this->fixQuote($type); + $result = 'SELECT column_name, data_type ' + . 'FROM information_schema.columns WHERE table_name=' + . $this->fixQuote($wordArray[2]) . ' AND column_name=' + . $this->fixQuote($wordArray[5]) + . ' AND data_type=' . $this->fixQuote($datatype); + + if ($datatype === 'character varying') + { + $result .= ' AND character_maximum_length = ' . (int) substr($type, $pos + 1); + } $this->queryType = 'CHANGE_COLUMN_TYPE'; - $this->msgElements = array($this->fixQuote($wordArray[2]), $this->fixQuote($wordArray[5]), $type); + $this->msgElements = array( + $this->fixQuote($wordArray[2]), + $this->fixQuote($wordArray[5]), + $type + ); } - elseif (strtoupper($wordArray[7] . ' ' . $wordArray[8]) === 'NOT NULL') + elseif ($alterAction === 'SET') { - if (strtoupper($wordArray[6]) === 'SET') + $alterType = strtoupper($wordArray[7]); + + if ($alterType === 'NOT' && strtoupper($wordArray[8]) === 'NULL') { - // SET NOT NULL - $isNullable = $this->fixQuote('NO'); + $result = 'SELECT column_name, data_type, is_nullable' + . ' FROM information_schema.columns' + . ' WHERE table_name=' . $this->fixQuote($wordArray[2]) + . ' AND column_name=' . $this->fixQuote($wordArray[5]) + . ' AND is_nullable=' . $this->fixQuote('NO'); + + $this->queryType = 'CHANGE_COLUMN_TYPE'; + $this->msgElements = array( + $this->fixQuote($wordArray[2]), + $this->fixQuote($wordArray[5]), + 'NOT NULL' + ); } - else + elseif ($alterType === 'DEFAULT') { - // DROP NOT NULL - $isNullable = $this->fixQuote('YES'); - } - - $result = 'SELECT column_name, data_type, is_nullable FROM information_schema.columns WHERE table_name=' - . $this->fixQuote($wordArray[2]) . ' AND column_name=' . $this->fixQuote($wordArray[5]) - . ' AND is_nullable=' . $isNullable; + $result = 'SELECT column_name, data_type, is_nullable' + . ' FROM information_schema.columns' + . ' WHERE table_name=' . $this->fixQuote($wordArray[2]) + . ' AND column_name=' . $this->fixQuote($wordArray[5]) + . ' AND (CASE (position(' . $this->db->quote('::') . ' in column_default))' + . ' WHEN 0 THEN ' + . ' column_default = ' . $this->db->quote($wordArray[8]) + . ' ELSE ' + . ' substring(column_default, 1, (position(' . $this->db->quote('::') + . ' in column_default) -1)) = ' . $this->db->quote($wordArray[8]) + . ' END)'; - $this->queryType = 'CHANGE_COLUMN_TYPE'; - $this->checkQueryExpected = 1; - $this->msgElements = array($this->fixQuote($wordArray[2]), $this->fixQuote($wordArray[5]), $isNullable); + $this->queryType = 'CHANGE_COLUMN_TYPE'; + $this->msgElements = array( + $this->fixQuote($wordArray[2]), + $this->fixQuote($wordArray[5]), + 'DEFAULT ' . $wordArray[8] + ); + } } - elseif (strtoupper($wordArray[7]) === 'DEFAULT') + elseif ($alterAction === 'DROP') { - if (strtoupper($wordArray[6]) === 'SET') + $alterType = strtoupper($wordArray[7]); + + if ($alterType === 'DEFAULT') { - $isNullDef = 'IS NOT NULL'; + $result = 'SELECT column_name, data_type, is_nullable , column_default' + . ' FROM information_schema.columns' + . ' WHERE table_name=' . $this->fixQuote($wordArray[2]) + . ' AND column_name=' . $this->fixQuote($wordArray[5]) + . ' AND column_default IS NOT NULL'; + + $this->queryType = 'CHANGE_COLUMN_TYPE'; + $this->checkQueryExpected = 0; + $this->msgElements = array( + $this->fixQuote($wordArray[2]), + $this->fixQuote($wordArray[5]), + 'NOT DEFAULT' + ); } - else + elseif ($alterType === 'NOT' && strtoupper($wordArray[8]) === 'NULL') { - // DROP DEFAULT - $isNullDef = 'IS NULL'; - } + $result = 'SELECT column_name, data_type, is_nullable , column_default' + . ' FROM information_schema.columns' + . ' WHERE table_name=' . $this->fixQuote($wordArray[2]) + . ' AND column_name=' . $this->fixQuote($wordArray[5]) + . ' AND is_nullable = ' . $this->fixQuote('NO'); - $result = 'SELECT column_name, data_type, column_default FROM information_schema.columns WHERE table_name=' - . $this->fixQuote($wordArray[2]) . ' AND column_name=' . $this->fixQuote($wordArray[5]) - . ' AND column_default ' . $isNullDef; - - $this->queryType = 'CHANGE_COLUMN_TYPE'; - $this->checkQueryExpected = 1; - $this->msgElements = array($this->fixQuote($wordArray[2]), $this->fixQuote($wordArray[5]), $isNullDef); + $this->queryType = 'CHANGE_COLUMN_TYPE'; + $this->checkQueryExpected = 0; + $this->msgElements = array( + $this->fixQuote($wordArray[2]), + $this->fixQuote($wordArray[5]), + 'NULL' + ); + } } } } From 8f5cc76454ceb0b92a6538741054215d845bee70 Mon Sep 17 00:00:00 2001 From: Tomasz Narloch Date: Mon, 19 Feb 2018 23:26:06 +0100 Subject: [PATCH 2/4] Add a better regex to split actions by comma --- .../src/Schema/ChangeItem/PostgresqlChangeItem.php | 13 ++++--------- 1 file changed, 4 insertions(+), 9 deletions(-) diff --git a/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php b/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php index f6a01791a2ab1..783bc75cb3425 100644 --- a/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php +++ b/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php @@ -43,7 +43,7 @@ protected function buildCheckQuery() $result = null; $splitIntoWords = "~'[^']*'(*SKIP)(*F)|\s+~"; - $splitIntoActions = "~'[^']*'(*SKIP)(*F)|,~"; + $splitIntoActions = "~'[^']*'(*SKIP)(*F)|\([^)]*\)(*SKIP)(*F)|,~"; // Remove any newlines $this->updateQuery = str_replace("\n", '', $this->updateQuery); @@ -121,14 +121,9 @@ protected function buildCheckQuery() if ($alterAction === 'TYPE') { - $type = ''; + $type = implode(' ', array_slice($wordArray, 7)); - for ($i = 7; $i < $totalWords; $i++) - { - $type .= $wordArray[$i] . ' '; - } - - if ($pos = stripos($type, 'USING')) + if ($pos = stripos($type, ' USING ')) { $type = substr($type, 0, $pos); } @@ -139,7 +134,7 @@ protected function buildCheckQuery() } else { - $datatype = substr($type, 0, -1); + $datatype = $type; } $result = 'SELECT column_name, data_type ' From 143e06954e3e860e9371022898a81ed40b87665b Mon Sep 17 00:00:00 2001 From: Tomasz Narloch Date: Tue, 20 Feb 2018 19:44:41 +0100 Subject: [PATCH 3/4] Remove useless code --- libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php | 4 +--- 1 file changed, 1 insertion(+), 3 deletions(-) diff --git a/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php b/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php index 783bc75cb3425..7cd59416cadf3 100644 --- a/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php +++ b/libraries/src/Schema/ChangeItem/PostgresqlChangeItem.php @@ -80,9 +80,7 @@ protected function buildCheckQuery() $lastActionArray = preg_split($splitIntoWords, end($actions), null, PREG_SPLIT_NO_EMPTY); // Replace all actions by the last one - array_splice($wordArray, 3, count($wordArray), $lastActionArray); - - $totalWords = count($wordArray); + array_splice($wordArray, 3, $totalWords, $lastActionArray); $alterCommand = strtoupper($wordArray[3] . ' ' . $wordArray[4]); From daed6e36469499d0b30662cf2bb15d70c593e3cf Mon Sep 17 00:00:00 2001 From: Tomasz Narloch Date: Thu, 17 May 2018 22:50:39 +0200 Subject: [PATCH 4/4] Add a comment to sql file --- .../components/com_admin/sql/updates/postgresql/3.1.0.sql | 6 +++++- 1 file changed, 5 insertions(+), 1 deletion(-) diff --git a/administrator/components/com_admin/sql/updates/postgresql/3.1.0.sql b/administrator/components/com_admin/sql/updates/postgresql/3.1.0.sql index 8b3b4974ad65a..d51b351a530b3 100644 --- a/administrator/components/com_admin/sql/updates/postgresql/3.1.0.sql +++ b/administrator/components/com_admin/sql/updates/postgresql/3.1.0.sql @@ -1,6 +1,10 @@ /* Changes to tables where data type conflicts exist with MySQL (mainly dealing with null values */ ALTER TABLE "#__modules" ALTER COLUMN "content" SET DEFAULT ''; ---ALTER TABLE "#__updates" ALTER COLUMN "data" SET DEFAULT ''; +-- +-- The following statement has to be disabled because it conflicts with +-- a later change added with Joomla! 3.8.8 to repair the update of database schema changes +-- +-- ALTER TABLE "#__updates" ALTER COLUMN "data" SET DEFAULT ''; /* Tags database schema */