diff --git a/config/module.config.php b/config/module.config.php index 1d44ff1d3d6ee77f91d6ba7a8556c77b4b4c7097..b22bd574d2de4664424c69390c15d47acccab92e 100755 --- a/config/module.config.php +++ b/config/module.config.php @@ -8,6 +8,8 @@ use UnicaenOracle\ORM\Query\Functions\Chr; use UnicaenOracle\ORM\Query\Functions\CompriseEntre; use UnicaenOracle\ORM\Query\Functions\Convert; use UnicaenOracle\ORM\Query\Functions\Replace; +use UnicaenOracle\Service\DataService; +use UnicaenOracle\Service\SchemaService; return [ 'doctrine' => [ @@ -36,4 +38,10 @@ return [ ], ], ], + 'service_manager' => [ + 'invokables' => [ + SchemaService::class => SchemaService::class, + DataService::class => DataService::class, + ] + ] ]; diff --git a/src/UnicaenOracle/Service/DataService.php b/src/UnicaenOracle/Service/DataService.php new file mode 100644 index 0000000000000000000000000000000000000000..8a17d4413b526f0564667645a546ace721c37d4d --- /dev/null +++ b/src/UnicaenOracle/Service/DataService.php @@ -0,0 +1,147 @@ +<?php + +namespace UnicaenOracle\Service; + +use Doctrine\DBAL\Connection; +use Doctrine\DBAL\DBALException; +use UnicaenApp\Exception\RuntimeException; + +class DataService +{ + + /** + * @param Connection $srcSchemaConn + * @param string $schemaName + * @param string[] $tableNames + * @param string $outputFilePathTemplate + * @return string[] + */ + public function createDataInsertsScriptFile(Connection $srcSchemaConn, $schemaName, array $tableNames, $outputFilePathTemplate) + { + try { + $stmt = $srcSchemaConn->prepare($this->generateSQLForTablesColumnsInfos($tableNames)); + $stmt->execute(); + } catch (DBALException $e) { + throw new RuntimeException("Erreur!", null, $e); + } + $results = $stmt->fetchAll(); + $preparedTablesMetadata = $this->prepareTablesMetadata($results); + //var_dump(prepareTablesMetadata($results)); + $outputFilePaths = []; + + foreach ($preparedTablesMetadata as $tableName => $columnsConfig) { + $outputFilePath = sprintf($outputFilePathTemplate, $tableName); + $fh = fopen($outputFilePath, 'w'); + fwrite($fh, "set define off ;" . PHP_EOL . PHP_EOL); + $sqlSelect = "SELECT * FROM $tableName"; + try { + $stmt = $srcSchemaConn->prepare($sqlSelect); + $stmt->execute(); + } catch (DBALException $e) { + throw new RuntimeException("Erreur!", null, $e); + } + while ($row = $stmt->fetch()) { + $tableMetadata = $preparedTablesMetadata[$tableName]; + $formattedColumnValues = []; + foreach ($tableMetadata as $columnName => $columnMetadata) { + $columnValue = $row[$columnName]; + if ($columnValue === null) { + $formattedColumnValue = 'NULL'; + } else { + $formatter = $columnMetadata['formatter']; + $formattedColumnValue = $formatter($columnValue); + } + $formattedColumnValues[$columnName] = $formattedColumnValue; + } + $columnNames = implode(', ', array_keys($formattedColumnValues)); + $columnValues = implode(', ', $formattedColumnValues); + $sqlInsert = "INSERT INTO $schemaName.$tableName ($columnNames) VALUES ($columnValues) ;"; + fwrite($fh, $sqlInsert . PHP_EOL); + } + fclose($fh); + $outputFilePaths[] = $outputFilePath; + } + sort($outputFilePaths); + + return $outputFilePaths; + } + + /** + * @param array $tableNames + * @return string + */ + function generateSQLForTablesColumnsInfos(array $tableNames) + { + $tables = implode(',', array_map(function ($tn) { + return "'$tn'"; + }, $tableNames)); + + return <<<EOS +select table_name, column_name, data_type +from all_tab_columns +where table_name in ($tables) +order by column_id +EOS; + } + + /** + * @param array $data + * @return array + */ + function prepareTablesMetadata(array $data) + { + $formatted = []; + foreach ($data as $row) { + $tableName = $row['TABLE_NAME']; + $colName = $row['COLUMN_NAME']; + $dataType = $row['DATA_TYPE']; + + switch ($dataType) { + case 'NUMBER': + $formatter = function ($value) { + return $value; + }; + break; + case 'VARCHAR2': + $formatter = function ($value) { + $value = str_replace("'", "''", $value); + + return "'$value'"; + }; + break; + case 'CLOB': + $formatter = function ($value) { + $value = str_replace("'", "''", $value); + // découpage en morceaux de 4000 caractères pour éviter l'erreur ORA-01704: string literal too long. + $lineEnding = '######'; + $lines = explode($lineEnding, rtrim(chunk_split($value, 4000, $lineEnding), $lineEnding)); + $toClobs = array_map(function ($value) { + return "TO_CLOB('$value')"; + }, $lines); + + return implode('||', $toClobs); + }; + break; + case 'DATE': + $formatter = function ($value) { + return "TO_DATE('$value', 'YYYY-MM-DD HH24:MI:SS')"; + }; + break; + default: + throw new RuntimeException("Type non prévu : $dataType"); + } + $cfg = [ + 'DATA_TYPE' => $dataType, + 'formatter' => $formatter, + ]; + + if (!isset($formatted[$tableName])) { + $formatted[$tableName] = []; + } + $formatted[$tableName][$colName] = $cfg; + } + + return $formatted; + } + +} \ No newline at end of file diff --git a/src/UnicaenOracle/Service/SchemaService.php b/src/UnicaenOracle/Service/SchemaService.php new file mode 100644 index 0000000000000000000000000000000000000000..eb2d3dbad1ce3224f5311d55addb38488b5d3f9d --- /dev/null +++ b/src/UnicaenOracle/Service/SchemaService.php @@ -0,0 +1,379 @@ +<?php + +namespace UnicaenOracle\Service; + +use Doctrine\DBAL\Connection; +use Doctrine\DBAL\DBALException; +use Doctrine\ORM\NoResultException; +use UnicaenApp\Exception\RuntimeException; + +/** + * + * + * @author Unicaen + */ +class SchemaService +{ + /** + * @param Connection $srcSchemaConn + * @param string $schemaName + * @param string $outputFilePath + * @throws NoResultException + */ + public function createSchemaClearingScriptFile(Connection $srcSchemaConn, $schemaName, $outputFilePath) + { + try { + $stmt = $srcSchemaConn->executeQuery($this->generateSQLForSchemaClearing($schemaName)); + $stmt->execute(); + } catch (DBALException $e) { + throw new RuntimeException("Erreur!", null, $e); + } + $result = $stmt->fetchAll(\PDO::FETCH_COLUMN); + if (count($result) === 0) { + throw new NoResultException(); + } + $sql = implode('', $result); + file_put_contents($outputFilePath, $sql); + } + + /** + * @param Connection $srcSchemaConn + * @param string $srcSchemaName + * @param string $dstSchemaName + * @param string $outputFilePath + */ + public function createSchemaCreationScriptFile(Connection $srcSchemaConn, $srcSchemaName, $dstSchemaName, $outputFilePath) + { + // config DBMS Metadata + try { + $stmt = $srcSchemaConn->executeQuery($this->generateSQLForDBMSMetadataPackageConfiguration()); + $stmt->execute(); + } catch (DBALException $e) { + throw new RuntimeException("Erreur!", null, $e); + } + // generate DDL + try { + $stmt = $srcSchemaConn->prepare($this->generateSQLForSchemaCreation($srcSchemaName)); + $stmt->execute(); + } catch (DBALException $e) { + throw new RuntimeException("Erreur!", null, $e); + } + $result = $stmt->fetchAll(\PDO::FETCH_COLUMN); + $sql = implode('', $result); + $sql = str_replace("\"$srcSchemaName\"", "\"$dstSchemaName\"", $sql); + file_put_contents($outputFilePath, $sql); + } + + /** + * @param string $schemaName + * @return string + */ + function generateSQLForSchemaClearing($schemaName) + { + return <<<EOS +-- +-- triggers +-- + +SELECT 'DROP TRIGGER ' || owner || '.' || trigger_NAME || ';' || chr(10) +FROM ALL_TRIGGERS +WHERE owner = '$schemaName' + +UNION ALL + + +-- +-- views +-- + +SELECT 'DROP VIEW ' || owner || '.' || view_name || ';' || chr(10) +FROM all_views +WHERE owner = '$schemaName' + +UNION ALL + + +-- +-- materialized views +-- + +SELECT 'DROP MATERIALIZED VIEW ' || owner || '.' || mview_name || ';' || chr(10) +FROM all_mviews +WHERE owner = '$schemaName' + +UNION ALL + + +-- +-- procedures and functions +-- + +SELECT 'DROP PROCEDURE ' || owner || '.' || OBJECT_NAME || ';' || chr(10) +FROM SYS.ALL_OBJECTS +WHERE owner = '$schemaName' + and UPPER(OBJECT_TYPE) = 'PROCEDURE' +UNION ALL +SELECT 'DROP FUNCTION ' || owner || '.' || OBJECT_NAME || ';' || chr(10) +FROM SYS.ALL_OBJECTS +WHERE owner = '$schemaName' + and UPPER(OBJECT_TYPE) = 'FUNCTION' + +UNION ALL + + +-- +-- packages +-- + +SELECT 'DROP PACKAGE ' || owner || '.' || OBJECT_NAME || ';' || chr(10) +FROM SYS.ALL_OBJECTS +WHERE owner = '$schemaName' + and UPPER(OBJECT_TYPE) = 'PACKAGE' + +UNION ALL + + +-- +-- sequences +-- + +SELECT 'DROP SEQUENCE ' || sequence_owner || '.' || sequence_name || ';' || chr(10) +FROM all_sequences +where sequence_owner = '$schemaName' + +UNION ALL + + +-- +-- indexes : supprimés avec les constraints ci-dessous +-- + +-- SELECT 'DROP INDEX ' || owner || '.' || index_name || ';' || chr(10) +-- FROM all_indexes +-- WHERE owner = '$schemaName' +-- +-- UNION ALL + + +-- +-- constraints +-- + +-- d'abord les FK +select 'ALTER TABLE ' || OWNER || '.' || table_name || ' drop CONSTRAINT ' || constraint_name || ';' || chr(10) +from all_constraints +where constraint_type = 'R' + and owner = '$schemaName' +union all +-- ensuite les PK +select 'ALTER TABLE ' || OWNER || '.' || table_name || ' drop CONSTRAINT ' || constraint_name || ';' || chr(10) +from all_constraints +where constraint_type = 'P' + and owner = '$schemaName' + +UNION ALL + + +-- +-- tables +-- + +SELECT 'DROP TABLE ' || owner || '.' || table_name || ' PURGE;' || chr(10) +FROM all_tables +WHERE owner = '$schemaName' and + table_name not in (select mview_name from all_mviews) -- exclusion des tables liées à des vues matérialisées +-- UNION ALL +-- select 'PURGE RECYCLEBIN;' +-- FROM all_tables +-- WHERE owner = '$schemaName' +-- and rownum = 1 + +EOS; + } + + /** + * @return string + */ + function generateSQLForDBMSMetadataPackageConfiguration() + { + return <<<EOS +-- +-- DBMS_METADATA config +-- + +begin + DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true); -- formatting the output with indentation and line feeds ? + DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true); -- appending a SQL terminator (; or /) to each DDL statement ? + -- + DBMS_METADATA.set_transform_param(DBMS_METADATA.SESSION_TRANSFORM, 'CONSTRAINTS_AS_ALTER', false); -- + DBMS_METADATA.set_transform_param(DBMS_METADATA.SESSION_TRANSFORM, 'CONSTRAINTS', true); -- including non-referential table constraints in the CREATE TABLE statement ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); -- including referential constraints (foreign keys) in the CREATE TABLE statement ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.session_transform, 'FORCE', true); -- using the FORCE keyword in the CREATE VIEW statement ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.session_transform, 'TABLESPACE', false); -- including tablespace clauses in the DDL ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.session_transform, 'SEGMENT_ATTRIBUTES', false); -- including segment attributes clauses (physical attributes, storage attributes, tablespace, logging) in the DDL ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.session_transform, 'STORAGE', false); -- including storage clauses in the DDL ? +end; + +EOS; + } + + /** + * @param string $schemaName + * @return string + */ + function generateSQLForSchemaCreation($schemaName) + { + return <<<EOS +-- +-- sequences +-- + +SELECT DBMS_METADATA.GET_DDL ('SEQUENCE', sequence_name, sequence_owner) as sql +FROM all_sequences +where sequence_owner = '$schemaName' + +UNION ALL + + +-- +-- tables +-- + +SELECT DBMS_METADATA.get_ddl ('TABLE', table_name, owner) as sql +FROM all_tables +WHERE owner = '$schemaName' and + table_name not in (select mview_name from all_mviews) -- exclusion des tables liées à des vues matérialisées + +UNION ALL + + +-- +-- constraints : unique +-- + +SELECT DBMS_METADATA.get_ddl ('CONSTRAINT', constraint_name, owner) as sql +from user_constraints +WHERE constraint_type in ('U') and -- unique type + index_name is null and -- écarte les contraintes liées automatiquement à un index car créées avec la table + table_name not in (select mview_name from all_mviews) -- exclusion des tables liées à des vues matérialisées + and owner = '$schemaName' + +UNION ALL + + +-- +-- indexes +-- + +SELECT DBMS_METADATA.get_ddl ('INDEX', index_name, owner) as sql +FROM all_indexes i +WHERE not exists (select * from user_constraints where index_name = i.index_name) -- écarte les index créés automatiquement car liés à une contrainte + and owner = '$schemaName' + +-- select * from all_indexes WHERE owner = '$schemaName'; + +UNION ALL + + +-- +-- packages +-- + +SELECT DBMS_METADATA.get_ddl ('PACKAGE_SPEC', OBJECT_NAME, owner) as sql +FROM SYS.ALL_OBJECTS +WHERE owner = '$schemaName' + and UPPER(OBJECT_TYPE) = 'PACKAGE' + +UNION ALL + + +-- +-- procedures and functions +-- + +SELECT DBMS_METADATA.get_ddl ('PROCEDURE', OBJECT_NAME, owner) as sql +FROM SYS.ALL_OBJECTS +WHERE owner = '$schemaName' + and UPPER(OBJECT_TYPE) = 'PROCEDURE' +UNION ALL +SELECT DBMS_METADATA.get_ddl ('FUNCTION', OBJECT_NAME, owner) as sql +FROM SYS.ALL_OBJECTS +WHERE owner = '$schemaName' + and UPPER(OBJECT_TYPE) = 'FUNCTION' + +UNION ALL + + +-- +-- packages +-- + +SELECT DBMS_METADATA.get_ddl ('PACKAGE_BODY', OBJECT_NAME, owner) as sql +FROM SYS.ALL_OBJECTS +WHERE owner = '$schemaName' + and UPPER(OBJECT_TYPE) = 'PACKAGE BODY' + +UNION ALL + + +-- +-- triggers +-- + +SELECT DBMS_METADATA.get_ddl ('TRIGGER', trigger_NAME, owner) as sql +FROM ALL_TRIGGERS +WHERE owner = '$schemaName' + +UNION ALL + + +-- +-- views +-- + +SELECT DBMS_METADATA.get_ddl ('VIEW', view_name, owner) as sql +FROM all_views +WHERE owner = '$schemaName' + +UNION ALL + + +-- +-- materialized views +-- + +SELECT DBMS_METADATA.get_ddl ('MATERIALIZED_VIEW', mview_name, owner) as sql +FROM all_mviews +WHERE owner = '$schemaName' + +UNION ALL + + +-- +-- data inserts +-- + +-- +-- [...] +-- + + +-- +-- constraints +-- + +--select DBMS_METADATA.GET_DDL('CONSTRAINT', constraint_name, owner) as sql +--from all_constraints +--where owner = '$schemaName' +-- and constraint_type = 'P' +--union all +select DBMS_METADATA.GET_DDL('REF_CONSTRAINT', constraint_name, owner) as sql +from all_constraints +where owner = '$schemaName' + and constraint_type = 'R' + + +EOS; + + } +} \ No newline at end of file diff --git a/src/UnicaenOracle/Service/scripts/clear_schema_ddl.sql b/src/UnicaenOracle/Service/scripts/clear_schema_ddl.sql new file mode 100644 index 0000000000000000000000000000000000000000..34e9d306961d4f250b443f69e5d1a2a8624fbfa1 --- /dev/null +++ b/src/UnicaenOracle/Service/scripts/clear_schema_ddl.sql @@ -0,0 +1,119 @@ + +-- +-- triggers +-- + +SELECT 'DROP TRIGGER ' || owner || '.' || trigger_NAME || ';' || chr(10) +FROM ALL_TRIGGERS +WHERE owner = 'SYGAL_TEST' + +UNION ALL + + +-- +-- views +-- + +SELECT 'DROP VIEW ' || owner || '.' || view_name || ';' || chr(10) +FROM all_views +WHERE owner = 'SYGAL_TEST' + +UNION ALL + + +-- +-- materialized views +-- + +SELECT 'DROP MATERIALIZED VIEW ' || owner || '.' || mview_name || ';' || chr(10) +FROM all_mviews +WHERE owner = 'SYGAL_TEST' + +UNION ALL + + +-- +-- procedures and functions +-- + +SELECT 'DROP PROCEDURE ' || owner || '.' || OBJECT_NAME || ';' || chr(10) +FROM SYS.ALL_OBJECTS +WHERE owner = 'SYGAL_TEST' + and UPPER(OBJECT_TYPE) = 'PROCEDURE' +UNION ALL +SELECT 'DROP FUNCTION ' || owner || '.' || OBJECT_NAME || ';' || chr(10) +FROM SYS.ALL_OBJECTS +WHERE owner = 'SYGAL_TEST' + and UPPER(OBJECT_TYPE) = 'FUNCTION' + +UNION ALL + + +-- +-- packages +-- + +SELECT 'DROP PACKAGE ' || owner || '.' || OBJECT_NAME || ';' || chr(10) +FROM SYS.ALL_OBJECTS +WHERE owner = 'SYGAL_TEST' + and UPPER(OBJECT_TYPE) = 'PACKAGE' + +UNION ALL + + +-- +-- sequences +-- + +SELECT 'DROP SEQUENCE ' || sequence_owner || '.' || sequence_name || ';' || chr(10) +FROM all_sequences +where sequence_owner = 'SYGAL_TEST' + +UNION ALL + + +-- +-- indexes : supprimés avec les constraints ci-dessous +-- + +-- SELECT 'DROP INDEX ' || owner || '.' || index_name || ';' || chr(10) +-- FROM all_indexes +-- WHERE owner = 'SYGAL_TEST' +-- +-- UNION ALL + + +-- +-- constraints +-- + +-- d'abord les FK +select 'ALTER TABLE ' || OWNER || '.' || table_name || ' drop CONSTRAINT ' || constraint_name || ';' || chr(10) +from all_constraints +where constraint_type = 'R' + and owner = 'SYGAL_TEST' +union all +-- ensuite les PK +select 'ALTER TABLE ' || OWNER || '.' || table_name || ' drop CONSTRAINT ' || constraint_name || ';' || chr(10) +from all_constraints +where constraint_type = 'P' + and owner = 'SYGAL_TEST' + +UNION ALL + + +-- +-- tables +-- + +SELECT 'DROP TABLE ' || owner || '.' || table_name || ' PURGE;' || chr(10) +FROM all_tables +WHERE owner = 'SYGAL_TEST' and + table_name not in (select mview_name from all_mviews) -- exclusion des tables liées à des vues matérialisées +-- UNION ALL +-- select 'PURGE RECYCLEBIN;' +-- FROM all_tables +-- WHERE owner = 'SYGAL_TEST' +-- and rownum = 1 + +; diff --git a/src/UnicaenOracle/Service/scripts/config_dbms_metadata.sql b/src/UnicaenOracle/Service/scripts/config_dbms_metadata.sql new file mode 100644 index 0000000000000000000000000000000000000000..2eedc57e9788d0934053c3808f2302237abaaf81 --- /dev/null +++ b/src/UnicaenOracle/Service/scripts/config_dbms_metadata.sql @@ -0,0 +1,17 @@ +-- +-- DBMS_METADATA config +-- + +begin + DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM, 'PRETTY', true); -- formatting the output with indentation and line feeds ? + DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM, 'SQLTERMINATOR', true); -- appending a SQL terminator (; or /) to each DDL statement ? + -- + DBMS_METADATA.set_transform_param(DBMS_METADATA.SESSION_TRANSFORM, 'CONSTRAINTS_AS_ALTER', false); + DBMS_METADATA.set_transform_param(DBMS_METADATA.SESSION_TRANSFORM, 'CONSTRAINTS', true); -- including non-referential table constraints in the CREATE TABLE statement ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.SESSION_TRANSFORM, 'REF_CONSTRAINTS', false); -- including referential constraints (foreign keys) in the CREATE TABLE statement ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.session_transform, 'FORCE', true); -- using the FORCE keyword in the CREATE VIEW statement ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.session_transform, 'TABLESPACE', false); -- including tablespace clauses in the DDL ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.session_transform, 'SEGMENT_ATTRIBUTES', false); -- including segment attributes clauses (physical attributes, storage attributes, tablespace, logging) in the DDL ? + DBMS_METADATA.set_transform_param(DBMS_METADATA.session_transform, 'STORAGE', false); -- including storage clauses in the DDL ? +end +; diff --git a/src/UnicaenOracle/Service/scripts/generate_schema_ddl.sql b/src/UnicaenOracle/Service/scripts/generate_schema_ddl.sql new file mode 100644 index 0000000000000000000000000000000000000000..b068544d716472710ff97f954926c885a15ddad2 --- /dev/null +++ b/src/UnicaenOracle/Service/scripts/generate_schema_ddl.sql @@ -0,0 +1,149 @@ +-- +-- sequences +-- + +SELECT DBMS_METADATA.GET_DDL ('SEQUENCE', sequence_name, sequence_owner) as sql +FROM all_sequences +where sequence_owner = 'SYGAL' + +UNION ALL + + +-- +-- tables +-- + +SELECT DBMS_METADATA.get_ddl ('TABLE', table_name, owner) as sql +FROM all_tables +WHERE owner = 'SYGAL' and + table_name not in (select mview_name from all_mviews) -- exclusion des tables liées à des vues matérialisées + +UNION ALL + + +-- +-- constraints : not null, unique +-- + +SELECT DBMS_METADATA.get_ddl ('CONSTRAINT', constraint_name, owner) as sql +from user_constraints +WHERE constraint_type in ('U') and + index_name is null and -- écarte les contraintes liées automatiquement à un index car créées avec la table + table_name not in (select mview_name from all_mviews) -- exclusion des tables liées à des vues matérialisées + and owner = 'SYGAL' + +-- select * from user_constraints WHERE owner = 'SYGAL'; + +UNION ALL + + +-- +-- indexes +-- + +SELECT DBMS_METADATA.get_ddl ('INDEX', index_name, owner) as sql +FROM all_indexes i +WHERE not exists (select * from user_constraints where index_name = i.index_name) -- écarte les index créés automatiquement car liés à une contrainte + and owner = 'SYGAL' + +-- select * from all_indexes WHERE owner = 'SYGAL'; + +UNION ALL + + +-- +-- packages +-- + +SELECT DBMS_METADATA.get_ddl ('PACKAGE_SPEC', OBJECT_NAME, owner) as sql +FROM SYS.ALL_OBJECTS +WHERE owner = 'SYGAL' + and UPPER(OBJECT_TYPE) = 'PACKAGE' + +UNION ALL + + +-- +-- procedures and functions +-- + +SELECT DBMS_METADATA.get_ddl ('PROCEDURE', OBJECT_NAME, owner) as sql +FROM SYS.ALL_OBJECTS +WHERE owner = 'SYGAL' + and UPPER(OBJECT_TYPE) = 'PROCEDURE' +UNION ALL +SELECT DBMS_METADATA.get_ddl ('FUNCTION', OBJECT_NAME, owner) as sql +FROM SYS.ALL_OBJECTS +WHERE owner = 'SYGAL' + and UPPER(OBJECT_TYPE) = 'FUNCTION' + +UNION ALL + + +-- +-- packages +-- + +SELECT DBMS_METADATA.get_ddl ('PACKAGE_BODY', OBJECT_NAME, owner) as sql +FROM SYS.ALL_OBJECTS +WHERE owner = 'SYGAL' + and UPPER(OBJECT_TYPE) = 'PACKAGE BODY' + +UNION ALL + + +-- +-- triggers +-- + +SELECT DBMS_METADATA.get_ddl ('TRIGGER', trigger_NAME, owner) as sql +FROM ALL_TRIGGERS +WHERE owner = 'SYGAL' + +UNION ALL + + +-- +-- views +-- + +SELECT DBMS_METADATA.get_ddl ('VIEW', view_name, owner) as sql +FROM all_views +WHERE owner = 'SYGAL' + +UNION ALL + + +-- +-- materialized views +-- + +SELECT DBMS_METADATA.get_ddl ('MATERIALIZED_VIEW', mview_name, owner) as sql +FROM all_mviews +WHERE owner = 'SYGAL' + +UNION ALL + + +-- +-- data inserts +-- + +-- +-- [...] +-- + + +-- +-- constraints +-- + +select DBMS_METADATA.GET_DDL('CONSTRAINT', constraint_name, owner) as sql +from all_constraints +where owner = 'SYGAL' + and constraint_type = 'P' +union all +select DBMS_METADATA.GET_DDL('REF_CONSTRAINT', constraint_name, owner) as sql +from all_constraints +where owner = 'SYGAL' + and constraint_type = 'R'