├── LICENSE ├── README.md ├── install.sql ├── plugzilla_meta.sql ├── plugzilla_pb.sql └── plugzilla_ps.sql /LICENSE: -------------------------------------------------------------------------------- 1 | Apache License 2 | Version 2.0, January 2004 3 | http://www.apache.org/licenses/ 4 | 5 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 6 | 7 | 1. Definitions. 8 | 9 | "License" shall mean the terms and conditions for use, reproduction, 10 | and distribution as defined by Sections 1 through 9 of this document. 11 | 12 | "Licensor" shall mean the copyright owner or entity authorized by 13 | the copyright owner that is granting the License. 14 | 15 | "Legal Entity" shall mean the union of the acting entity and all 16 | other entities that control, are controlled by, or are under common 17 | control with that entity. For the purposes of this definition, 18 | "control" means (i) the power, direct or indirect, to cause the 19 | direction or management of such entity, whether by contract or 20 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 21 | outstanding shares, or (iii) beneficial ownership of such entity. 22 | 23 | "You" (or "Your") shall mean an individual or Legal Entity 24 | exercising permissions granted by this License. 25 | 26 | "Source" form shall mean the preferred form for making modifications, 27 | including but not limited to software source code, documentation 28 | source, and configuration files. 29 | 30 | "Object" form shall mean any form resulting from mechanical 31 | transformation or translation of a Source form, including but 32 | not limited to compiled object code, generated documentation, 33 | and conversions to other media types. 34 | 35 | "Work" shall mean the work of authorship, whether in Source or 36 | Object form, made available under the License, as indicated by a 37 | copyright notice that is included in or attached to the work 38 | (an example is provided in the Appendix below). 39 | 40 | "Derivative Works" shall mean any work, whether in Source or Object 41 | form, that is based on (or derived from) the Work and for which the 42 | editorial revisions, annotations, elaborations, or other modifications 43 | represent, as a whole, an original work of authorship. For the purposes 44 | of this License, Derivative Works shall not include works that remain 45 | separable from, or merely link (or bind by name) to the interfaces of, 46 | the Work and Derivative Works thereof. 47 | 48 | "Contribution" shall mean any work of authorship, including 49 | the original version of the Work and any modifications or additions 50 | to that Work or Derivative Works thereof, that is intentionally 51 | submitted to Licensor for inclusion in the Work by the copyright owner 52 | or by an individual or Legal Entity authorized to submit on behalf of 53 | the copyright owner. For the purposes of this definition, "submitted" 54 | means any form of electronic, verbal, or written communication sent 55 | to the Licensor or its representatives, including but not limited to 56 | communication on electronic mailing lists, source code control systems, 57 | and issue tracking systems that are managed by, or on behalf of, the 58 | Licensor for the purpose of discussing and improving the Work, but 59 | excluding communication that is conspicuously marked or otherwise 60 | designated in writing by the copyright owner as "Not a Contribution." 61 | 62 | "Contributor" shall mean Licensor and any individual or Legal Entity 63 | on behalf of whom a Contribution has been received by Licensor and 64 | subsequently incorporated within the Work. 65 | 66 | 2. Grant of Copyright License. Subject to the terms and conditions of 67 | this License, each Contributor hereby grants to You a perpetual, 68 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 69 | copyright license to reproduce, prepare Derivative Works of, 70 | publicly display, publicly perform, sublicense, and distribute the 71 | Work and such Derivative Works in Source or Object form. 72 | 73 | 3. Grant of Patent License. Subject to the terms and conditions of 74 | this License, each Contributor hereby grants to You a perpetual, 75 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 76 | (except as stated in this section) patent license to make, have made, 77 | use, offer to sell, sell, import, and otherwise transfer the Work, 78 | where such license applies only to those patent claims licensable 79 | by such Contributor that are necessarily infringed by their 80 | Contribution(s) alone or by combination of their Contribution(s) 81 | with the Work to which such Contribution(s) was submitted. If You 82 | institute patent litigation against any entity (including a 83 | cross-claim or counterclaim in a lawsuit) alleging that the Work 84 | or a Contribution incorporated within the Work constitutes direct 85 | or contributory patent infringement, then any patent licenses 86 | granted to You under this License for that Work shall terminate 87 | as of the date such litigation is filed. 88 | 89 | 4. Redistribution. You may reproduce and distribute copies of the 90 | Work or Derivative Works thereof in any medium, with or without 91 | modifications, and in Source or Object form, provided that You 92 | meet the following conditions: 93 | 94 | (a) You must give any other recipients of the Work or 95 | Derivative Works a copy of this License; and 96 | 97 | (b) You must cause any modified files to carry prominent notices 98 | stating that You changed the files; and 99 | 100 | (c) You must retain, in the Source form of any Derivative Works 101 | that You distribute, all copyright, patent, trademark, and 102 | attribution notices from the Source form of the Work, 103 | excluding those notices that do not pertain to any part of 104 | the Derivative Works; and 105 | 106 | (d) If the Work includes a "NOTICE" text file as part of its 107 | distribution, then any Derivative Works that You distribute must 108 | include a readable copy of the attribution notices contained 109 | within such NOTICE file, excluding those notices that do not 110 | pertain to any part of the Derivative Works, in at least one 111 | of the following places: within a NOTICE text file distributed 112 | as part of the Derivative Works; within the Source form or 113 | documentation, if provided along with the Derivative Works; or, 114 | within a display generated by the Derivative Works, if and 115 | wherever such third-party notices normally appear. The contents 116 | of the NOTICE file are for informational purposes only and 117 | do not modify the License. You may add Your own attribution 118 | notices within Derivative Works that You distribute, alongside 119 | or as an addendum to the NOTICE text from the Work, provided 120 | that such additional attribution notices cannot be construed 121 | as modifying the License. 122 | 123 | You may add Your own copyright statement to Your modifications and 124 | may provide additional or different license terms and conditions 125 | for use, reproduction, or distribution of Your modifications, or 126 | for any such Derivative Works as a whole, provided Your use, 127 | reproduction, and distribution of the Work otherwise complies with 128 | the conditions stated in this License. 129 | 130 | 5. Submission of Contributions. Unless You explicitly state otherwise, 131 | any Contribution intentionally submitted for inclusion in the Work 132 | by You to the Licensor shall be under the terms and conditions of 133 | this License, without any additional terms or conditions. 134 | Notwithstanding the above, nothing herein shall supersede or modify 135 | the terms of any separate license agreement you may have executed 136 | with Licensor regarding such Contributions. 137 | 138 | 6. Trademarks. This License does not grant permission to use the trade 139 | names, trademarks, service marks, or product names of the Licensor, 140 | except as required for reasonable and customary use in describing the 141 | origin of the Work and reproducing the content of the NOTICE file. 142 | 143 | 7. Disclaimer of Warranty. Unless required by applicable law or 144 | agreed to in writing, Licensor provides the Work (and each 145 | Contributor provides its Contributions) on an "AS IS" BASIS, 146 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 147 | implied, including, without limitation, any warranties or conditions 148 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 149 | PARTICULAR PURPOSE. You are solely responsible for determining the 150 | appropriateness of using or redistributing the Work and assume any 151 | risks associated with Your exercise of permissions under this License. 152 | 153 | 8. Limitation of Liability. In no event and under no legal theory, 154 | whether in tort (including negligence), contract, or otherwise, 155 | unless required by applicable law (such as deliberate and grossly 156 | negligent acts) or agreed to in writing, shall any Contributor be 157 | liable to You for damages, including any direct, indirect, special, 158 | incidental, or consequential damages of any character arising as a 159 | result of this License or out of the use or inability to use the 160 | Work (including but not limited to damages for loss of goodwill, 161 | work stoppage, computer failure or malfunction, or any and all 162 | other commercial damages or losses), even if such Contributor 163 | has been advised of the possibility of such damages. 164 | 165 | 9. Accepting Warranty or Additional Liability. While redistributing 166 | the Work or Derivative Works thereof, You may choose to offer, 167 | and charge a fee for, acceptance of support, warranty, indemnity, 168 | or other liability obligations and/or rights consistent with this 169 | License. However, in accepting such obligations, You may act only 170 | on Your own behalf and on Your sole responsibility, not on behalf 171 | of any other Contributor, and only if You agree to indemnify, 172 | defend, and hold each Contributor harmless for any liability 173 | incurred by, or claims asserted against, such Contributor by reason 174 | of your accepting any such warranty or additional liability. 175 | 176 | END OF TERMS AND CONDITIONS 177 | 178 | APPENDIX: How to apply the Apache License to your work. 179 | 180 | To apply the Apache License to your work, attach the following 181 | boilerplate notice, with the fields enclosed by brackets "[]" 182 | replaced with your own identifying information. (Don't include 183 | the brackets!) The text should be enclosed in the appropriate 184 | comment syntax for the file format. We also recommend that a 185 | file or class name and description of purpose be included on the 186 | same "printed page" as the copyright notice for easier 187 | identification within third-party archives. 188 | 189 | Copyright [yyyy] [name of copyright owner] 190 | 191 | Licensed under the Apache License, Version 2.0 (the "License"); 192 | you may not use this file except in compliance with the License. 193 | You may obtain a copy of the License at 194 | 195 | http://www.apache.org/licenses/LICENSE-2.0 196 | 197 | Unless required by applicable law or agreed to in writing, software 198 | distributed under the License is distributed on an "AS IS" BASIS, 199 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 200 | See the License for the specific language governing permissions and 201 | limitations under the License. -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # plugzilla 2 | 3 | Cloning a pluggable database takes time, and for environments where you'd like to use clones as part of unit testing, or other elements of Agile development, it would be nice to be able to bring a clone into operation in the smallest time possible. One mechanism for that is sparse storage clones aka snapshot copy, but depending on your version and your storage infrastructure, you might hit some limitations. So this package allows you clone pluggable databases extremely quickly by having pluggable database pre-cloned in advance. 4 | 5 | ## Example 6 | 7 | Lets say you have a dev pluggable database called PDB1. You want to let developers take clones of this as quickly and as often as they like and at various stages in its lifecycle. Here how we might do it with plugzilla. 8 | 9 | 1) On Sunday June 1st, we've just built (say) version 3.1 of our app into PDB1. I want a frozen copy of PDB1 that can be used as a seed for developers to clone. So I'll do: 10 | 11 | ```console 12 | SQL> set serverout on 13 | SQL> exec plugzilla.new_seed_from_existing(p_source=>'PDB1',p_seed=>'PDB31'); 14 | alter session set container = cdb$root 15 | seed=SEED_PDB31 16 | src=PDB1,mode=READ WRITE 17 | alter pluggable database PDB1 close immediate 18 | alter pluggable database PDB1 open read only 19 | create pluggable database SEED_PDB31 from PDB1 file_name_convert=('PDB1','SEED_PDB31') 20 | alter pluggable database SEED_PDB31 open restricted 21 | alter pluggable database SEED_PDB31 close immediate 22 | alter pluggable database SEED_PDB31 open read only 23 | alter pluggable database PDB1 close immediate 24 | alter pluggable database PDB1 open 25 | alter session set container = cdb$root 26 | 27 | PL/SQL procedure successfully completed. 28 | ``` 29 | 30 | This will create a pluggable database called SEED_PDB31 (all the seeds will have the prefix "SEED_", but see the package constants if you want to change this) 31 | 32 | 2) On Wednesday June 4th, we've just built (say) version 3.2 of our app into PDB1. I again want a frozen copy of PDB1 that can be used as a seed for developers to clone. So I'll do: 33 | 34 | ```console 35 | SQL> exec plugzilla.new_seed_from_existing(p_source=>'PDB1',p_seed=>'PDB32'); 36 | alter session set container = cdb$root 37 | seed=SEED_PDB32 38 | src=PDB1,mode=READ WRITE 39 | alter pluggable database PDB1 close immediate 40 | alter pluggable database PDB1 open read only 41 | create pluggable database SEED_PDB32 from PDB1 file_name_convert=('PDB1','SEED_PDB32') 42 | alter pluggable database SEED_PDB32 open restricted 43 | alter pluggable database SEED_PDB32 close immediate 44 | alter pluggable database SEED_PDB32 open read only 45 | alter pluggable database PDB1 close immediate 46 | alter pluggable database PDB1 open 47 | alter session set container = cdb$root 48 | 49 | PL/SQL procedure successfully completed. 50 | ``` 51 | 52 | So now we have two seed copies of PDB1 at different points in time. These are the pluggables that are the base for any developer to clone from. 53 | 54 | 3) We now call plugzilla.preclone (although more likely is that you would have this as a scheduler job). This will look for any seeds (we have 2 from above) and pre-create 'n' pluggable copies of those databases where 'n is defined by the package constant 'g_reserve_copies' 55 | 56 | ```console 57 | SQL> exec plugzilla.preclone 58 | alter session set container = cdb$root 59 | Processing seed: SEED_PDB31 60 | - pending clones: 0 61 | - building 3 pre-clones 62 | create pluggable database PEND_PDB3100001 from SEED_PDB31 file_name_convert=('SEED_PDB31','PEND_PDB3100001') 63 | create pluggable database PEND_PDB3100002 from SEED_PDB31 file_name_convert=('SEED_PDB31','PEND_PDB3100002') 64 | create pluggable database PEND_PDB3100003 from SEED_PDB31 file_name_convert=('SEED_PDB31','PEND_PDB3100003') 65 | Processing seed: SEED_PDB32 66 | - pending clones: 0 67 | - building 3 pre-clones 68 | create pluggable database PEND_PDB3200001 from SEED_PDB32 file_name_convert=('SEED_PDB32','PEND_PDB3200001') 69 | create pluggable database PEND_PDB3200002 from SEED_PDB32 file_name_convert=('SEED_PDB32','PEND_PDB3200002') 70 | create pluggable database PEND_PDB3200003 from SEED_PDB32 file_name_convert=('SEED_PDB32','PEND_PDB3200003') 71 | alter session set container = cdb$root 72 | 73 | PL/SQL procedure successfully completed. 74 | ``` 75 | 76 | These "pending" clones are fully operational pluggables that are yet to be claimed by a developer. They are pre-created so that when a developer wants a clone, they can do it very quickly. 77 | 78 | 4) A developer wants a sandbox pluggable of the application as of version 3.1. They simply ask for one 79 | 80 | ```console 81 | SQL> exec plugzilla.clone_from_seed('PDB31') 82 | alter session set container = cdb$root 83 | Found pending pdb PEND_PDB3100001 to use 84 | alter pluggable database PEND_PDB3100001 open restricted 85 | alter session set container = PEND_PDB3100001 86 | alter pluggable database PEND_PDB3100001 rename global_name to PDB3100001 87 | alter pluggable database PDB3100001 close immediate 88 | alter pluggable database PDB3100001 open 89 | alter session set container = cdb$root 90 | 91 | PL/SQL procedure successfully completed. 92 | ``` 93 | 94 | The first available pending pluggable database is picked from the list and renamed to PDB31001. This is an automatically generated name, but developers can choose their own. Because this is just a rename, the developer will have their pluggable *irrespective* of size available to them within 5-10 seconds. 95 | 96 | If we want a second sandbox clone, this time with a custom name, I'll simply run the routine again 97 | 98 | ```console 99 | SQL> exec plugzilla.clone_from_seed('PDB31','MYDB') 100 | alter session set container = cdb$root 101 | Found pending pdb PEND_PDB3100002 to use 102 | alter pluggable database PEND_PDB3100002 open restricted 103 | alter session set container = PEND_PDB3100002 104 | alter pluggable database PEND_PDB3100002 rename global_name to MYDB 105 | alter pluggable database MYDB close immediate 106 | alter pluggable database MYDB open 107 | alter session set container = cdb$root 108 | 109 | PL/SQL procedure successfully completed. 110 | ``` 111 | 112 | 5) When the developer is done with their clone, they drop it. 113 | 114 | 115 | ```console 116 | SQL> exec plugzilla.drop_clone('MYDB') 117 | alter session set container = cdb$root 118 | Dropping clone MYDB 119 | alter pluggable database MYDB close immediate 120 | drop pluggable database MYDB including datafiles 121 | alter session set container = cdb$root 122 | 123 | PL/SQL procedure successfully completed. 124 | ``` 125 | 126 | Note that this does not "return" the pluggable to the pool of available pluggables, because that database could contain changes which means it will have diverged from its initial seed. It is completely dropped and the space freed up. It is 'preclone' alone that keeps a preallocation of pluggables available. Because the numeric suffix continues to rise, there is a cap of 99999 pluggables that could be created. If your application is not deployed by then, you've got bigger issues to worry about :-) 127 | 128 | At any time, the table contains the state of plugzilla. After the above operations, it would look like this: 129 | 130 | ```console 131 | SQL> select * from plugzilla_meta; 132 | 133 | RELATIONSHIP CHILD PARENT 134 | ------------------------------ -------------------- ----------------- 135 | SEED_FROM_PDB SEED_PDB31 PDB1 => we took a seed PDB31 from PDB1 136 | SEED_FROM_PDB SEED_PDB32 PDB1 => we took a seed PDB32 from PDB1 137 | PENDING_CLONE PEND_PDB3100003 SEED_PDB31 => preclone built these 138 | PENDING_CLONE PEND_PDB3200001 SEED_PDB32 139 | PENDING_CLONE PEND_PDB3200002 SEED_PDB32 140 | PENDING_CLONE PEND_PDB3200003 SEED_PDB32 141 | CLONE_FROM_SEED PDB3100001 SEED_PDB31 => we took a preclone and converted it to a clone 142 | ``` 143 | 144 | Notes 145 | 146 | 1) There are many many options in terms of cloning for pluggable databases. This package goes with the Keep-It-Simple policy. It is going to clone pluggables by 147 | 148 | - making the source read only 149 | - cloning the datafiles replacing existing pluggable name with a new one 150 | 151 | 2) As you'd expect, this software comes WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 152 | 153 | 3) Don't forget - you're messing with pluggable databases here. Don't be THAT person that drops all your data! 154 | 155 | 4) Notice when a pending pluggable becomes owned by a developer, the files are not being moved or renamed. This is done to keep the operation nice and snappy. 156 | 157 | # LICENSE 158 | 159 | Licensed under the Apache License, Version 2.0 (the "License"); 160 | you may not use this file except in compliance with the License. 161 | You may obtain a copy of the License at 162 | 163 | http://www.apache.org/licenses/LICENSE-2.0 164 | 165 | Unless required by applicable law or agreed to in writing, software 166 | distributed under the License is distributed on an "AS IS" BASIS, 167 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 168 | See the License for the specific language governing permissions and 169 | limitations under the License. -------------------------------------------------------------------------------- /install.sql: -------------------------------------------------------------------------------- 1 | whenever sqlerror exit 2 | begin 3 | if user != 'SYS' then 4 | raise_application_error(-20000,'You should be SYS for this'); 5 | end if; 6 | end; 7 | / 8 | 9 | begin 10 | if sys_context('USERENV','CON_NAME') != 'CDB$ROOT' then 11 | raise_application_error(-20000,'You should be in CDB$ROOT for this'); 12 | end if; 13 | end; 14 | / 15 | whenever sqlerror continue 16 | 17 | prompt 18 | prompt Warning: This install will drop the PLUGZILLA_META if it already exists. 19 | prompt 20 | prompt If you are just re-installing the packages, this could be a bad idea because you 21 | prompt lose the state of your current pluggables 22 | prompt 23 | prompt Press Ctrl-C now if you want to abort 24 | pause 25 | 26 | 27 | @@plugzilla_meta.sql 28 | @@plugzilla_pb.sql 29 | @@plugzilla_ps.sql -------------------------------------------------------------------------------- /plugzilla_meta.sql: -------------------------------------------------------------------------------- 1 | set echo on 2 | drop table plugzilla_meta purge; 3 | create table plugzilla_meta 4 | ( relationship varchar2(30), 5 | child varchar2(128), 6 | parent varchar2(128), 7 | constraint plugzilla_meta_chk check ( relationship in ('SEED_FROM_PDB','CLONE_FROM_SEED','PENDING_CLONE') ) 8 | ); 9 | set echo off -------------------------------------------------------------------------------- /plugzilla_pb.sql: -------------------------------------------------------------------------------- 1 | create or replace 2 | package body plugzilla is 3 | g_seed_prefix constant varchar2(10) := 'SEED_'; 4 | g_pend_prefix constant varchar2(10) := 'PEND_'; 5 | g_reserve_copies constant int := 3; 6 | 7 | g_seed_from_pdb constant varchar2(30) := 'SEED_FROM_PDB'; 8 | g_clone_from_seed constant varchar2(30) := 'CLONE_FROM_SEED'; 9 | g_pending_clone constant varchar2(30) := 'PENDING_CLONE'; 10 | 11 | procedure msg(m varchar2) is 12 | begin 13 | dbms_output.put_line(m); 14 | end; 15 | 16 | procedure release_usage(p_from_die boolean default false); 17 | 18 | procedure die(m varchar2) is 19 | begin 20 | release_usage(p_from_die=>true); 21 | raise_application_error(-20100,m); 22 | end; 23 | 24 | procedure ddl(m varchar2) is 25 | begin 26 | msg(m); 27 | execute immediate m; 28 | end; 29 | 30 | procedure set_root is 31 | begin 32 | if sys_context('USERENV','CON_NAME') != 'CDB$ROOT' then 33 | ddl('alter session set container = cdb$root'); 34 | end if; 35 | end; 36 | 37 | procedure serialise_usage is 38 | l_lock_handle varchar2(128); 39 | l_lock_status number; 40 | begin 41 | set_root; 42 | dbms_lock.allocate_unique ( 43 | 'PLUGZILLA', 44 | l_lock_handle); 45 | 46 | l_lock_status := dbms_lock.request( 47 | lockhandle=>l_lock_handle, 48 | timeout=>0, 49 | release_on_commit=>false); 50 | 51 | if l_lock_status not in (0,4) then 52 | die('Could not serialize access to PLUGZILLA. One person at a time only, status came back as '||l_lock_status); 53 | end if; 54 | 55 | end; 56 | 57 | procedure release_usage(p_from_die boolean default false) is 58 | l_lock_handle varchar2(128); 59 | l_lock_status number; 60 | begin 61 | set_root; 62 | dbms_lock.allocate_unique ( 63 | 'PLUGZILLA', 64 | l_lock_handle); 65 | 66 | l_lock_status := dbms_lock.release( 67 | lockhandle=>l_lock_handle); 68 | 69 | if not p_from_die then 70 | if l_lock_status != 0 then 71 | die('Abnormal error trying to release lock, status came back as '||l_lock_status); 72 | end if; 73 | end if; 74 | end; 75 | 76 | procedure cheeky_hacker(p_pdb varchar2) is 77 | begin 78 | if p_pdb like '%$%' then 79 | die('Why on earth are you tinkering with pluggable names that contain a $????'); 80 | end if; 81 | end; 82 | 83 | function pdb_exists(p_pdb varchar2) return boolean is 84 | l_exists int; 85 | begin 86 | cheeky_hacker(p_pdb); 87 | 88 | select count(*) into l_exists 89 | from v$pdbs 90 | where name = p_pdb; 91 | return l_exists > 0; 92 | end; 93 | 94 | function pdb_mode(p_pdb varchar2) return varchar2 is 95 | l_mode varchar2(20); 96 | begin 97 | cheeky_hacker(p_pdb); 98 | select open_mode into l_mode 99 | from v$pdbs 100 | where name = p_pdb; 101 | return l_mode; 102 | exception 103 | when no_data_found then 104 | die('Pluggable '||p_pdb||' could not be found'); 105 | end; 106 | 107 | function clean_seed(p_seed varchar2) return varchar2 is 108 | l_seed varchar2(128); 109 | begin 110 | cheeky_hacker(p_seed); 111 | l_seed := 112 | ltrim(rtrim( 113 | case 114 | when instr(upper(p_seed),upper(g_seed_prefix)) = 1 then upper(substr(p_seed,length(g_seed_prefix)+1)) 115 | else upper(p_seed) 116 | end 117 | )); 118 | if l_seed is null then 119 | die('Seed must not be null. Did you miss something after the prefix?'); 120 | end if; 121 | if regexp_replace(l_seed,'[[:alnum:]]+') is not null then 122 | die('Seed must be simple alphanumerics'); 123 | end if; 124 | 125 | return upper(g_seed_prefix)||l_seed; 126 | end; 127 | 128 | procedure new_seed_from_existing(p_source varchar2, p_seed varchar2,p_read_write_after_create boolean default false) is 129 | l_exists int; 130 | l_mode varchar2(20); 131 | l_source varchar2(128) := upper(ltrim(rtrim(p_source))); 132 | l_seed varchar2(128) := clean_seed(p_seed); 133 | begin 134 | serialise_usage; 135 | 136 | -- 137 | -- seed must not exist 138 | -- 139 | if pdb_exists(l_seed) then 140 | die('Pluggable '||l_seed||' already exists'); 141 | end if; 142 | 143 | -- 144 | -- source must exist, and must not be already involved in plugzilla in an inappropriate way 145 | -- 146 | l_mode := pdb_mode(l_source); 147 | 148 | select count(*) 149 | into l_exists 150 | from plugzilla_meta 151 | where child = l_source; 152 | if l_exists > 0 then 153 | die('Pluggable '||l_source||' is listed as a child in plugzilla. That sounds like a mess'); 154 | end if; 155 | 156 | msg('seed='||l_seed); 157 | msg('src='||l_source||',mode='||l_mode); 158 | 159 | if l_mode = 'MOUNTED' then 160 | ddl('alter pluggable database '||l_source||' open restricted'); 161 | ddl('alter pluggable database '||l_source||' close immediate'); 162 | ddl('alter pluggable database '||l_source||' open read only'); 163 | elsif l_mode = 'READ WRITE' then 164 | ddl('alter pluggable database '||l_source||' close immediate'); 165 | ddl('alter pluggable database '||l_source||' open read only'); 166 | end if; 167 | 168 | ddl('create pluggable database '||l_seed||' from '||l_source||' '|| 169 | 'file_name_convert=('''||l_source||''','''||l_seed||''')'); 170 | 171 | if p_read_write_after_create then 172 | ddl('alter pluggable database '||l_seed||' open'); 173 | else 174 | ddl('alter pluggable database '||l_seed||' open restricted'); 175 | ddl('alter pluggable database '||l_seed||' close immediate'); 176 | ddl('alter pluggable database '||l_seed||' open read only'); 177 | end if; 178 | delete from plugzilla_meta 179 | where relationship = g_seed_from_pdb 180 | and child = l_seed; 181 | 182 | -- 183 | -- reset the state of the source 184 | -- 185 | if l_mode = 'MOUNTED' then 186 | ddl('alter pluggable database '||l_source||' close immediate'); 187 | elsif l_mode = 'READ WRITE' then 188 | ddl('alter pluggable database '||l_source||' close immediate'); 189 | ddl('alter pluggable database '||l_source||' open'); 190 | end if; 191 | 192 | 193 | insert into plugzilla_meta (relationship,child,parent) 194 | values (g_seed_from_pdb,l_seed,l_source); 195 | commit; 196 | release_usage; 197 | end; 198 | 199 | procedure clone_from_seed(p_seed varchar2, p_clone varchar2 default 'AUTO', p_wait_for_preclone boolean default false) is 200 | l_seed varchar2(128) := clean_seed(p_seed); 201 | l_clone varchar2(128) := upper(ltrim(rtrim(p_clone))); 202 | l_mode varchar2(20); 203 | l_pend_pdb varchar2(128); 204 | begin 205 | serialise_usage; 206 | -- 207 | -- seed must exist 208 | -- 209 | if not pdb_exists(l_seed) then 210 | die('Pluggable '||l_seed||'does not exist'); 211 | end if; 212 | 213 | -- 214 | -- clone must not exist 215 | -- 216 | if pdb_exists(l_clone) then 217 | die('Pluggable '||l_clone||' already exists'); 218 | end if; 219 | 220 | -- 221 | -- then aim here is a pending clone is always there ready, otherwise 222 | -- we might cop a wait for preclone 223 | -- 224 | for i in 1 .. 2 225 | loop 226 | begin 227 | select child 228 | into l_pend_pdb 229 | from 230 | ( select child 231 | from plugzilla_meta 232 | where parent = l_seed 233 | and relationship = g_pending_clone 234 | order by child 235 | ) 236 | where rownum = 1; 237 | exit; 238 | exception 239 | when no_data_found then 240 | if p_wait_for_preclone then 241 | if i = 1 then 242 | msg('No available pending pdbs, waiting for preclone to set one up for us'); 243 | plugzilla.preclone(l_seed); 244 | else 245 | die('Waited for preclone to run, and we still had no pending clones. This should never happen'); 246 | end if; 247 | else 248 | die('No available pending pdbs found. Perhaps run preclone'); 249 | end if; 250 | end; 251 | end loop; 252 | msg('Found pending pdb '||l_pend_pdb||' to use'); 253 | if l_clone = 'AUTO' then 254 | l_clone := substr(l_pend_pdb,length(g_pend_prefix)+1); 255 | -- 256 | -- one extra check for AUTO 257 | -- 258 | if pdb_exists(l_clone) then 259 | die('Pluggable '||l_clone||' already exists'); 260 | end if; 261 | end if; 262 | 263 | l_mode := pdb_mode(l_pend_pdb); 264 | 265 | if l_mode != 'MOUNTED' then 266 | ddl('alter pluggable database '||l_pend_pdb||' close immediate'); 267 | end if; 268 | 269 | ddl('alter pluggable database '||l_pend_pdb||' open restricted'); 270 | ddl('alter session set container = '||l_pend_pdb); 271 | ddl('alter pluggable database '||l_pend_pdb||' rename global_name to '||l_clone); 272 | ddl('alter pluggable database '||l_clone||' close immediate'); 273 | ddl('alter pluggable database '||l_clone||' open'); 274 | 275 | set_root; 276 | 277 | update plugzilla_meta 278 | set relationship = g_clone_from_seed, 279 | child = l_clone 280 | where child = l_pend_pdb 281 | and parent = l_seed 282 | and relationship = g_pending_clone; 283 | commit; 284 | release_usage; 285 | end; 286 | 287 | procedure drop_clone(p_clone varchar2, p_sync boolean default false) is 288 | l_exists int; 289 | l_clone varchar2(128) := upper(ltrim(rtrim(p_clone))); 290 | l_children varchar2(1000); 291 | l_mode varchar2(20); 292 | begin 293 | serialise_usage; 294 | -- 295 | -- clone must exist 296 | -- 297 | l_mode := pdb_mode(l_clone); 298 | 299 | -- 300 | -- 2 possible clone types here 301 | -- 302 | -- first is a pending clone, easiest to handle 303 | -- 304 | select count(*) 305 | into l_exists 306 | from plugzilla_meta 307 | where relationship in (g_pending_clone,g_clone_from_seed) 308 | and child = l_clone; 309 | 310 | if l_exists > 0 311 | then 312 | msg('Dropping clone '||l_clone); 313 | if l_mode != 'MOUNTED' then 314 | ddl('alter pluggable database '||l_clone||' close immediate'); 315 | end if; 316 | ddl('drop pluggable database '||l_clone||' including datafiles'); 317 | delete 318 | from plugzilla_meta 319 | where relationship in (g_pending_clone,g_clone_from_seed) 320 | and child = l_clone; 321 | commit; 322 | else 323 | die('Pluggable '||l_clone||' not found a clone or pending clone in Plugzilla'); 324 | end if; 325 | 326 | release_usage; 327 | end; 328 | 329 | procedure drop_seed(p_seed varchar2, p_sync boolean default false) is 330 | l_seed varchar2(128) := clean_seed(p_seed); 331 | l_children varchar2(1000); 332 | begin 333 | serialise_usage; 334 | if not pdb_exists(l_seed) then 335 | die('Pluggable '||l_seed||' does not exist'); 336 | end if; 337 | 338 | select listagg(child,',') within group ( order by child ) 339 | into l_children 340 | from plugzilla_meta 341 | where relationship in (g_clone_from_seed,g_pending_clone) 342 | and parent = l_seed; 343 | 344 | if l_children is not null then 345 | die('Seed '||l_seed||' has the following children which must be dropped first with DROP_CLONE: '||l_children); 346 | end if; 347 | 348 | ddl('alter pluggable database '||l_seed||' close immediate'); 349 | ddl('drop pluggable database '||l_seed||' including datafiles'); 350 | 351 | delete 352 | from plugzilla_meta 353 | where relationship = g_seed_from_pdb 354 | and child = l_seed; 355 | commit; 356 | release_usage; 357 | end; 358 | 359 | procedure drop_all_clones(p_seed varchar2, p_sync boolean default false) is 360 | l_seed varchar2(128) := clean_seed(p_seed); 361 | begin 362 | for i in ( select child 363 | from plugzilla_meta 364 | where parent = l_seed 365 | and relationship in (g_clone_from_seed,g_pending_clone) ) 366 | loop 367 | drop_clone(i.child,p_sync); 368 | end loop; 369 | end; 370 | 371 | 372 | procedure preclone(p_seed varchar2 default null) is 373 | l_pending int; 374 | l_pend_hwm int; 375 | l_mode varchar2(20); 376 | l_pend_pdb varchar2(128); 377 | begin 378 | serialise_usage; 379 | if p_seed is not null then 380 | cheeky_hacker(p_seed); 381 | end if; 382 | 383 | for i in ( select child 384 | from plugzilla_meta 385 | where relationship = g_seed_from_pdb 386 | and child = nvl(p_seed,child) 387 | ) 388 | loop 389 | msg('Processing seed: '||i.child); 390 | select count(*), nvl(to_number(max(substr(child,-3))),0) 391 | into l_pending, l_pend_hwm 392 | from plugzilla_meta 393 | where relationship = g_pending_clone 394 | and parent = i.child; 395 | msg('- pending clones: '||l_pending); 396 | 397 | if l_pending < g_reserve_copies then 398 | msg('- building '||(g_reserve_copies-l_pending)||' pre-clones'); 399 | l_mode := pdb_mode(i.child); 400 | 401 | if l_mode = 'MOUNTED' then 402 | ddl('alter pluggable database '||i.child||' open restricted'); 403 | ddl('alter pluggable database '||i.child||' close immediate'); 404 | ddl('alter pluggable database '||i.child||' open read only'); 405 | elsif l_mode = 'READ WRITE' then 406 | ddl('alter pluggable database '||i.child||' close immediate'); 407 | ddl('alter pluggable database '||i.child||' open read only'); 408 | end if; 409 | 410 | for j in l_pend_hwm+1 .. ( l_pend_hwm + g_reserve_copies - l_pending ) 411 | loop 412 | l_pend_pdb := g_pend_prefix||substr(i.child,length(g_seed_prefix)+1)||to_char(j,'fm00000'); 413 | 414 | ddl('create pluggable database '||l_pend_pdb||' from '||i.child||' '|| 415 | 'file_name_convert=('''||i.child||''','''||l_pend_pdb||''')'); 416 | 417 | insert into plugzilla_meta (relationship,child,parent) 418 | values (g_pending_clone,l_pend_pdb,i.child); 419 | commit; 420 | 421 | end loop; 422 | 423 | -- 424 | -- reset the state of the seed 425 | -- 426 | if l_mode = 'MOUNTED' then 427 | ddl('alter pluggable database '||i.child||' close immediate'); 428 | elsif l_mode = 'READ WRITE' then 429 | ddl('alter pluggable database '||i.child||' close immediate'); 430 | ddl('alter pluggable database '||i.child||' open'); 431 | end if; 432 | 433 | end if; 434 | end loop; 435 | release_usage; 436 | end; 437 | 438 | 439 | end; 440 | / 441 | sho err -------------------------------------------------------------------------------- /plugzilla_ps.sql: -------------------------------------------------------------------------------- 1 | create or replace 2 | package plugzilla is 3 | 4 | procedure new_seed_from_existing(p_source varchar2, p_seed varchar2,p_read_write_after_create boolean default false); 5 | procedure clone_from_seed(p_seed varchar2, p_clone varchar2 default 'AUTO', p_wait_for_preclone boolean default false); 6 | procedure drop_clone(p_clone varchar2, p_sync boolean default false); 7 | procedure drop_seed(p_seed varchar2, p_sync boolean default false); 8 | procedure drop_all_clones(p_seed varchar2, p_sync boolean default false); 9 | procedure preclone(p_seed varchar2 default null); 10 | 11 | end; 12 | / 13 | sho err 14 | --------------------------------------------------------------------------------