[Mastering Oracle SQLcl Liquibase - Part 2/3] Track your DEV database changes and move it to UAT(or any other environment)

In the previous episode, we learned to capture all objects from the DEV schema and move them to UAT. In this part, I will make a few changes on DEV and move them to UAT.

I won't have to think about what should be moved to UAT and in which order. SQLcl Liquibase will do it for me.

Sounds good? Read further.

If you want to follow this guide, please read part 1 first.

Make some changes to the DEV environment.

Change procedure

Create new table

create table locations
       (location_id    number(4),
         street_address varchar2(40),
         postal_code    varchar2(12),
         city       varchar2(30)
      constraint     loc_city_nn  not null,
         state_province varchar2(25),
         country_id     char(2)
       );
   create unique index loc_id_pk
   on locations (location_id);
   alter table locations
   add (constraint loc_id_pk
                 primary key (location_id),
         constraint loc_c_id_fk
                 foreign key (country_id)
                references countries(country_id)
       );

create or replace procedure secure_dml
is
begin
   if TO_CHAR(SYSDATE, 'HH24:MI') not between '08:00' and '18:00'
      or TO_CHAR(SYSDATE, 'DY') in ('SAT', 'SUN')
   then
      RAISE_APPLICATION_ERROR(-20205,
                              'This is a change for this blog.You may only make changes during normal office hours');
   end if;
end secure_dml;

Export changed DEV database schema.

There are two ways to do it (I am logged into DEV schema using SQLcl and located in /database/ folder)

  1. Export all objects from the DEV schema.
  • remove everything from /database/ folder (all files generated using generate-schema command from part 1 of the blog)

  • and generate DEV schema again by executing this command (SQLcl doesn't replace existing files, that's why I had to remove them first)

      liquibase generate-schema --split
    
  • if you are tracking your changes with GIT, you will notice that there are 3 changes:

  • Changed "secure_dml" procedure, new "locations" table and new line added to controller.xml

This way to export is simpler because SQLcl Liquibase will automatically handle all objects and add what is needed to controller.xml. However, generating a full schema can take some time, especially with bigger databases.

  1. Export only new/changed objects
  • go into /database/procedure/

  • remove secure_dml_procedure.xml

  • and export a new version of secure_dml procedure

liquibase generate-object --object-type procedure --object-name secure_dml
  • go into /database/table/

  • export your newly created table

liquibase generate-object --object-type table --object-name locations
  • manually add a line with a new table to controller.xml

That way of exporting objects is much faster and allows you to add only your changes to version control tools like GIT. Yet you need to remember to add new lines to controller.xml in the correct order.

Update UAT with new or changed objects.

After exporting the actual version of the DEV schema, I can start moving changes to my UAT.

Log into UAT using SQLcl (if you wonder how I set up a connection that way, check this SQLcl's new feature)

Check what changes will be moved from DEV to UAT by executing update-sql command (this command doesn't change anything in a database)

liquibase update-sql --changelog-file controller.xml --output-file preview.sql

Review generated file, and please notice that besides some things that Liquibase logs into %DATABASECHANGELOG% objects, there are 2 changes:

  • new LOCATIONS table

  • updated version of SECURE_DML procedure

Looks good. I will move those changes to UAT using update command.

liquibase update --changelog-file controller.xml

Check new rows with changesets in the DATABASECHANGELOG table.

Or exact SQL that was executed for every changeset.

Now, my DEV and UAT environments are equal, having the same amount and versions of objects.

Rafal.