From 42d8d456a295e1e87c92780aea45edec09a877cf Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 6 Oct 2018 13:02:16 +0100 Subject: [PATCH 01/83] Initial check in --- .../data_values/ut_compound_data_value.tpb | 42 ++++++++++++++----- .../data_values/ut_compound_data_value.tps | 3 +- .../data_values/ut_data_value_refcursor.tpb | 11 +++-- .../data_values/ut_data_value_refcursor.tps | 3 +- source/expectations/ut_expectation.tpb | 20 +++++++++ source/expectations/ut_expectation.tps | 9 +++- .../expectations/ut_expectation_compound.tpb | 31 +++++++++++++- .../expectations/ut_expectation_compound.tps | 6 +++ 8 files changed, 107 insertions(+), 18 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 113c5153e..9f3fd078d 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -194,7 +194,8 @@ create or replace type body ut_compound_data_value as return l_result; end; - member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean ) return integer is + member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, + a_unordered boolean , a_inclusion_compare boolean := false ) return integer is l_other ut_compound_data_value; l_ut_owner varchar2(250) := ut_utils.ut_owner; l_column_filter varchar2(32767); @@ -249,7 +250,11 @@ create or replace type body ut_compound_data_value as tgt.pk_hash = src.pk_hash ]' using a_exclude_xpath, a_include_xpath,a_join_by_xpath,self.data_id, l_other.data_id; - /* Peform minus on two sets two get diffrences that will be used later on to print results */ + /*!* + * Comparision is based on type of search, for inclusion based search we will look for left join only. + * For normal two side diff we will peform minus on two sets two get diffrences. + * SELF is expected + */ execute immediate 'insert into ' || l_ut_owner || '.ut_compound_data_diff_tmp ( diff_id,item_hash,pk_hash,duplicate_no) with source_data as ( select t.data_id,t.item_hash,row_number() over (partition by t.pk_hash,t.item_hash,t.data_id order by 1,2) duplicate_no, @@ -258,30 +263,47 @@ create or replace type body ut_compound_data_value as where data_id = :self_guid or data_id = :other_guid ) select distinct :diff_id,tmp.item_hash,tmp.pk_hash,tmp.duplicate_no - from( + from( ( select t.item_hash,t. duplicate_no,t.pk_hash from source_data t - where t.data_id = :self_guid + where t.data_id = :other_guid minus select t.item_hash,t. duplicate_no,t.pk_hash from source_data t - where t.data_id = :other_guid + where t.data_id = :self_guid ) union all ( select t.item_hash,t. duplicate_no,t.pk_hash from source_data t - where t.data_id = :other_guid + where t.data_id = :self_guid ' + || + case when a_inclusion_compare then + ' and 1 = 2 ' + else + null + end || + ' minus select t.item_hash,t. duplicate_no,t.pk_hash from source_data t - where t.data_id = :self_guid - ))tmp' + where t.data_id = :other_guid ' + || + case when a_inclusion_compare then + ' and 1 = 2 ' + else + null + end || + ' + ) + ) + tmp' using self.data_id, l_other.data_id, l_diff_id, - self.data_id, l_other.data_id, - l_other.data_id,self.data_id; + l_other.data_id,self.data_id, + self.data_id, l_other.data_id; + --result is OK only if both are same if sql%rowcount = 0 and self.elements_count = l_other.elements_count then l_result := 0; diff --git a/source/expectations/data_values/ut_compound_data_value.tps b/source/expectations/data_values/ut_compound_data_value.tps index bf942c92e..f1c4e6529 100644 --- a/source/expectations/data_values/ut_compound_data_value.tps +++ b/source/expectations/data_values/ut_compound_data_value.tps @@ -44,6 +44,7 @@ create or replace type ut_compound_data_value force under ut_data_value( overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return clob, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2) return integer, - member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean ) return integer + member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, + a_unordered boolean , a_inclusion_compare boolean := false) return integer ) not final not instantiable / diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 1c7619be0..12bacd70b 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -220,7 +220,8 @@ create or replace type body ut_data_value_refcursor as return l_result_string; end; - overriding member function compare_implementation (a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return integer is + overriding member function compare_implementation (a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, + a_unordered boolean, a_inclusion_compare boolean := false) return integer is l_result integer := 0; l_other ut_data_value_refcursor; function is_pk_missing (a_pk_missing_tab ut_compound_data_helper.tt_missing_pk) return integer is @@ -236,7 +237,8 @@ create or replace type body ut_data_value_refcursor as --if we join by key and key is missing fail and report error if a_join_by_xpath is not null then - l_result := is_pk_missing(ut_compound_data_helper.is_pk_exists(self.key_info, l_other.key_info, a_exclude_xpath, a_include_xpath,a_join_by_xpath)); + l_result := is_pk_missing(ut_compound_data_helper.is_pk_exists(self.key_info, l_other.key_info, a_exclude_xpath, + a_include_xpath,a_join_by_xpath)); end if; if l_result = 0 then @@ -246,9 +248,10 @@ create or replace type body ut_data_value_refcursor as then l_result := 1; end if; - + if a_unordered then - l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, a_join_by_xpath, a_unordered); + l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, + a_join_by_xpath, a_unordered, a_inclusion_compare); else l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath); end if; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 02ded0b39..38582224f 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -44,7 +44,8 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), overriding member function to_string return varchar2, overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, - overriding member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return integer, + overriding member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, + a_unordered boolean, a_inclusion_compare boolean := false) return integer, overriding member function is_empty return boolean ) diff --git a/source/expectations/ut_expectation.tpb b/source/expectations/ut_expectation.tpb index 26e0c1092..0ca9c406b 100644 --- a/source/expectations/ut_expectation.tpb +++ b/source/expectations/ut_expectation.tpb @@ -679,5 +679,25 @@ create or replace type body ut_expectation as self.not_to( ut_be_less_than (a_expected) ); end; + member procedure to_include(self in ut_expectation, a_expected sys_refcursor) is + begin + self.to_( ut_include(a_expected) ); + end; + + member procedure to_contain(self in ut_expectation, a_expected sys_refcursor) is + begin + self.to_( ut_include(a_expected) ); + end; + + member procedure not_to_include(self in ut_expectation, a_expected sys_refcursor) is + begin + self.not_to( ut_include(a_expected) ); + end; + + member procedure not_to_contain(self in ut_expectation, a_expected sys_refcursor) is + begin + self.not_to( ut_include(a_expected) ); + end; + end; / diff --git a/source/expectations/ut_expectation.tps b/source/expectations/ut_expectation.tps index d27a18377..99183d022 100644 --- a/source/expectations/ut_expectation.tps +++ b/source/expectations/ut_expectation.tps @@ -158,7 +158,14 @@ create or replace type ut_expectation authid current_user as object( member procedure not_to_be_less_than(self in ut_expectation, a_expected timestamp_unconstrained), member procedure not_to_be_less_than(self in ut_expectation, a_expected timestamp_ltz_unconstrained), member procedure not_to_be_less_than(self in ut_expectation, a_expected timestamp_tz_unconstrained), - member procedure not_to_be_less_than(self in ut_expectation, a_expected yminterval_unconstrained) + member procedure not_to_be_less_than(self in ut_expectation, a_expected yminterval_unconstrained), + + member procedure to_include(self in ut_expectation, a_expected sys_refcursor), + member procedure to_contain(self in ut_expectation, a_expected sys_refcursor), + + member procedure not_to_include(self in ut_expectation, a_expected sys_refcursor), + member procedure not_to_contain(self in ut_expectation, a_expected sys_refcursor) + ) not final / diff --git a/source/expectations/ut_expectation_compound.tpb b/source/expectations/ut_expectation_compound.tpb index c620ec39c..cee16bdbd 100644 --- a/source/expectations/ut_expectation_compound.tpb +++ b/source/expectations/ut_expectation_compound.tpb @@ -34,7 +34,6 @@ create or replace type body ut_expectation_compound as self.not_to( ut_be_empty() ); end; - member procedure to_have_count(self in ut_expectation_compound, a_expected integer) is begin self.to_( ut_have_count(a_expected) ); @@ -76,6 +75,36 @@ create or replace type body ut_expectation_compound as return l_result; end; + member function to_include(a_expected sys_refcursor) return ut_expectation_compound is + l_result ut_expectation_compound := self; + begin + l_result.matcher := ut_include(a_expected); + return l_result; + end; + + member function to_contain(a_expected sys_refcursor) return ut_expectation_compound is + l_result ut_expectation_compound := self; + begin + l_result.matcher := ut_include(a_expected); + return l_result; + end; + + member function not_to_include(a_expected sys_refcursor) return ut_expectation_compound is + l_result ut_expectation_compound := self; + begin + l_result.matcher := ut_include(a_expected); + l_result.negated := ut_utils.boolean_to_int(true); + return l_result; + end; + + member function not_to_contain(a_expected sys_refcursor) return ut_expectation_compound is + l_result ut_expectation_compound := self; + begin + l_result.matcher := ut_include(a_expected); + l_result.negated := ut_utils.boolean_to_int(true); + return l_result; + end; + member function include(a_items varchar2) return ut_expectation_compound is l_result ut_expectation_compound; begin diff --git a/source/expectations/ut_expectation_compound.tps b/source/expectations/ut_expectation_compound.tps index 529b8875d..15b1874fe 100644 --- a/source/expectations/ut_expectation_compound.tps +++ b/source/expectations/ut_expectation_compound.tps @@ -29,6 +29,12 @@ create or replace type ut_expectation_compound under ut_expectation( member function to_equal(a_expected sys_refcursor, a_nulls_are_equal boolean := null) return ut_expectation_compound, member function not_to_equal(a_expected anydata, a_nulls_are_equal boolean := null) return ut_expectation_compound, member function not_to_equal(a_expected sys_refcursor, a_nulls_are_equal boolean := null) return ut_expectation_compound, + + member function to_include(a_expected sys_refcursor) return ut_expectation_compound, + member function to_contain(a_expected sys_refcursor) return ut_expectation_compound, + member function not_to_include(a_expected sys_refcursor) return ut_expectation_compound, + member function not_to_contain(a_expected sys_refcursor) return ut_expectation_compound, + member function include(a_items varchar2) return ut_expectation_compound, member function include(a_items ut_varchar2_list) return ut_expectation_compound, member procedure include(self in ut_expectation_compound, a_items varchar2), From 2360ca4f00be24b42d5b748eed216c973d973a95 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 6 Oct 2018 13:27:58 +0100 Subject: [PATCH 02/83] First working stab. No messages defined. --- .../data_values/ut_compound_data_value.tpb | 24 ++++++++++++------- source/expectations/matchers/ut_equal.tps | 4 ++-- 2 files changed, 17 insertions(+), 11 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 9f3fd078d..8e0001455 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -204,6 +204,7 @@ create or replace type body ut_compound_data_value as l_row_diffs ut_compound_data_helper.tt_row_diffs; c_max_rows constant integer := 20; + l_test varchar2(32000); function get_column_pk_hash(a_join_by_xpath varchar2) return varchar2 is l_column varchar2(32767); begin @@ -267,17 +268,17 @@ create or replace type body ut_compound_data_value as ( select t.item_hash,t. duplicate_no,t.pk_hash from source_data t - where t.data_id = :other_guid + where t.data_id = :self_guid minus select t.item_hash,t. duplicate_no,t.pk_hash from source_data t - where t.data_id = :self_guid + where t.data_id = :other_guid ) union all ( select t.item_hash,t. duplicate_no,t.pk_hash from source_data t - where t.data_id = :self_guid ' + where t.data_id = :other_guid ' || case when a_inclusion_compare then ' and 1 = 2 ' @@ -288,7 +289,7 @@ create or replace type body ut_compound_data_value as minus select t.item_hash,t. duplicate_no,t.pk_hash from source_data t - where t.data_id = :other_guid ' + where t.data_id = :self_guid ' || case when a_inclusion_compare then ' and 1 = 2 ' @@ -301,11 +302,16 @@ create or replace type body ut_compound_data_value as tmp' using self.data_id, l_other.data_id, l_diff_id, - l_other.data_id,self.data_id, - self.data_id, l_other.data_id; - - --result is OK only if both are same - if sql%rowcount = 0 and self.elements_count = l_other.elements_count then + self.data_id, l_other.data_id, + l_other.data_id,self.data_id; + + /*!* + * Result OK when is not inclusion matcher and both are the same + * Resullt OK when is inclusion matcher and left contains right set + */ + if sql%rowcount = 0 and self.elements_count = l_other.elements_count and not(a_inclusion_compare ) then + l_result := 0; + elsif sql%rowcount = 0 and a_inclusion_compare then l_result := 0; else l_result := 1; diff --git a/source/expectations/matchers/ut_equal.tps b/source/expectations/matchers/ut_equal.tps index 9968dba7f..ce2c9ed92 100644 --- a/source/expectations/matchers/ut_equal.tps +++ b/source/expectations/matchers/ut_equal.tps @@ -1,4 +1,4 @@ -create or replace type ut_equal under ut_comparison_matcher( +create or replace type ut_equal force under ut_comparison_matcher( /* utPLSQL - Version 3 Copyright 2016 - 2018 utPLSQL Project @@ -70,4 +70,4 @@ create or replace type ut_equal under ut_comparison_matcher( overriding member function failure_message(a_actual ut_data_value) return varchar2, overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2 ) -/ +not final From dd639709f1f8cbb980a16b73045720ae375fcaca Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 6 Oct 2018 15:03:25 +0100 Subject: [PATCH 03/83] Include matcher --- .../data_values/ut_compound_data_helper.pkb | 87 +++++++++++++++++++ .../data_values/ut_compound_data_helper.pks | 2 + .../data_values/ut_compound_data_value.tpb | 64 +++----------- 3 files changed, 101 insertions(+), 52 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index e6665bd10..4193c7f4a 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -540,5 +540,92 @@ create or replace package body ut_compound_data_helper is return l_no_missing_keys; end; + function get_unordered(a_owner in varchar2) return varchar2 is + l_sql varchar2(32767); + begin + l_sql := 'with source_data as + ( select t.data_id,t.item_hash,row_number() over (partition by t.pk_hash,t.item_hash,t.data_id order by 1,2) duplicate_no, + pk_hash + from ' || a_owner || '.ut_compound_data_tmp t + where data_id = :self_guid or data_id = :other_guid + ) + select distinct :diff_id,tmp.item_hash,tmp.pk_hash,tmp.duplicate_no + from( + ( + select t.item_hash,t. duplicate_no,t.pk_hash + from source_data t + where t.data_id = :self_guid + minus + select t.item_hash,t. duplicate_no,t.pk_hash + from source_data t + where t.data_id = :other_guid + ) + union all + ( + select t.item_hash,t. duplicate_no,t.pk_hash + from source_data t + where t.data_id = :other_guid + minus + select t.item_hash,t. duplicate_no,t.pk_hash + from source_data t + where t.data_id = :self_guid + ))tmp'; + return l_sql; + end; + + function get_inclusion_matcher_sql(a_owner in varchar2) return varchar2 is + l_sql varchar2(32767); + begin + l_sql := 'with source_data as + ( select t.data_id,t.item_hash,row_number() over (partition by t.pk_hash,t.item_hash,t.data_id order by 1,2) duplicate_no, + pk_hash + from ' || a_owner || '.ut_compound_data_tmp t + where data_id = :self_guid or data_id = :other_guid + ) + select distinct :diff_id,tmp.item_hash,tmp.pk_hash,tmp.duplicate_no + from( + ( + select t.item_hash,t. duplicate_no,t.pk_hash + from source_data t + where t.data_id = :self_guid + minus + select t.item_hash,t. duplicate_no,t.pk_hash + from source_data t + where t.data_id = :other_guid + ) + union all + ( + select t.item_hash,t. duplicate_no,t.pk_hash + from source_data t, + source_data s + where t.data_id = :other_guid + and s.data_id = :self_guid + and t.pk_hash = s.pk_hash + ) + ) + tmp'; + return l_sql; + end; + + function get_inclusion_matcher_not_sql(a_owner in varchar2) return varchar2 is + begin + null; + end; + + function get_refcursor_matcher_sql(a_owner in varchar2,a_inclusion_matcher boolean := false, a_negated_match boolean := false) return varchar2 is + l_sql varchar2(32767); + begin + l_sql := 'insert into ' || a_owner || '.ut_compound_data_diff_tmp ( diff_id,item_hash,pk_hash,duplicate_no)'||chr(10); + if a_inclusion_matcher and not(a_negated_match) then + l_sql := l_sql || get_inclusion_matcher_sql(a_owner); + elsif a_inclusion_matcher and a_negated_match then + null; + elsif not(a_inclusion_matcher) then + l_sql := l_sql || get_unordered(a_owner); + end if; + + return l_sql; + end; + end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index ab3693920..32512e391 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -81,5 +81,7 @@ create or replace package ut_compound_data_helper authid definer is function is_pk_exists(a_expected_cursor xmltype, a_actual_cursor xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2,a_join_by_xpath varchar2) return tt_missing_pk; + function get_refcursor_matcher_sql(a_owner in varchar2,a_inclusion_matcher boolean := false, a_negated_match boolean := false) return varchar2; + end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 8e0001455..a9c101ade 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -202,9 +202,9 @@ create or replace type body ut_compound_data_value as l_diff_id ut_compound_data_helper.t_hash; l_result integer; l_row_diffs ut_compound_data_helper.tt_row_diffs; - c_max_rows constant integer := 20; + c_max_rows constant integer := 20; + l_sql varchar2(32767); - l_test varchar2(32000); function get_column_pk_hash(a_join_by_xpath varchar2) return varchar2 is l_column varchar2(32767); begin @@ -254,56 +254,16 @@ create or replace type body ut_compound_data_value as /*!* * Comparision is based on type of search, for inclusion based search we will look for left join only. * For normal two side diff we will peform minus on two sets two get diffrences. - * SELF is expected + * SELF is expected. + * Due to growing complexity I have moved a dynamic SQL into helper package. */ - execute immediate 'insert into ' || l_ut_owner || '.ut_compound_data_diff_tmp ( diff_id,item_hash,pk_hash,duplicate_no) - with source_data as - ( select t.data_id,t.item_hash,row_number() over (partition by t.pk_hash,t.item_hash,t.data_id order by 1,2) duplicate_no, - pk_hash - from ' || l_ut_owner || '.ut_compound_data_tmp t - where data_id = :self_guid or data_id = :other_guid - ) - select distinct :diff_id,tmp.item_hash,tmp.pk_hash,tmp.duplicate_no - from( - ( - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :self_guid - minus - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :other_guid - ) - union all - ( - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :other_guid ' - || - case when a_inclusion_compare then - ' and 1 = 2 ' - else - null - end || - ' - minus - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :self_guid ' - || - case when a_inclusion_compare then - ' and 1 = 2 ' - else - null - end || - ' - ) - ) - tmp' - using self.data_id, l_other.data_id, - l_diff_id, - self.data_id, l_other.data_id, - l_other.data_id,self.data_id; + l_sql := ut_compound_data_helper.get_refcursor_matcher_sql(l_ut_owner,a_inclusion_compare); + + execute immediate l_sql + using self.data_id, l_other.data_id, + l_diff_id, + self.data_id, l_other.data_id, + l_other.data_id,self.data_id; /*!* * Result OK when is not inclusion matcher and both are the same @@ -311,7 +271,7 @@ create or replace type body ut_compound_data_value as */ if sql%rowcount = 0 and self.elements_count = l_other.elements_count and not(a_inclusion_compare ) then l_result := 0; - elsif sql%rowcount = 0 and a_inclusion_compare then + elsif sql%rowcount = 0 and a_inclusion_compare then l_result := 0; else l_result := 1; From 81240fbeb7507e11435fab4f01be51eba549a961 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 6 Oct 2018 15:26:57 +0100 Subject: [PATCH 04/83] Updated install and deinstall --- source/expectations/matchers/ut_include.tpb | 65 +++++++++++++++++++++ source/expectations/matchers/ut_include.tps | 25 ++++++++ source/install.sql | 2 + source/uninstall_objects.sql | 2 + 4 files changed, 94 insertions(+) create mode 100644 source/expectations/matchers/ut_include.tpb create mode 100644 source/expectations/matchers/ut_include.tps diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb new file mode 100644 index 000000000..cb6eedcda --- /dev/null +++ b/source/expectations/matchers/ut_include.tpb @@ -0,0 +1,65 @@ +create or replace type body ut_include as + /* + utPLSQL - Version 3 + Copyright 2016 - 2018 utPLSQL Project + + Licensed under the Apache License, Version 2.0 (the "License"): + you may not use this file except in compliance with the License. + You may obtain a copy of the License at + + http://www.apache.org/licenses/LICENSE-2.0 + + Unless required by applicable law or agreed to in writing, software + distributed under the License is distributed on an "AS IS" BASIS, + WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + See the License for the specific language governing permissions and + limitations under the License. + */ + + member procedure init(self in out nocopy ut_include, a_expected ut_data_value) is + begin + self.self_type := $$plsql_unit; + self.expected := a_expected; + self.include_list := ut_varchar2_list(); + self.exclude_list := ut_varchar2_list(); + self.join_columns := ut_varchar2_list(); + end; + + constructor function ut_include(self in out nocopy ut_include, a_expected sys_refcursor) return self as result is + begin + init(ut_data_value_refcursor(a_expected)); + return; + end; + + member function get_inclusion_compare return boolean is + begin + return true; + end; + + overriding member function run_matcher(self in out nocopy ut_include, a_actual ut_data_value) return boolean is + l_result boolean; + begin + if self.expected.data_type = a_actual.data_type then + l_result := 0 = treat(self.expected as ut_data_value_refcursor).compare_implementation(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), + true,get_inclusion_compare()); + else + l_result := (self as ut_matcher).run_matcher(a_actual); + end if; + return l_result; + end; + + overriding member function failure_message(a_actual ut_data_value) return varchar2 is + l_result varchar2(32767); + begin + if self.expected.data_type = a_actual.data_type and self.expected.is_diffable then + l_result := + 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() + || chr(10) || 'Diff:' || expected.diff(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), true); + else + l_result := (self as ut_matcher).failure_message(a_actual) || ': '|| self.expected.to_string_report(); + end if; + return l_result; + end; + +end; +/ diff --git a/source/expectations/matchers/ut_include.tps b/source/expectations/matchers/ut_include.tps new file mode 100644 index 000000000..2896832be --- /dev/null +++ b/source/expectations/matchers/ut_include.tps @@ -0,0 +1,25 @@ +create or replace type ut_include under ut_equal( + /* + utPLSQL - Version 3 + Copyright 2016 - 2018 utPLSQL Project + + Licensed under the Apache License, Version 2.0 (the "License"): + you may not use this file except in compliance with the License. + You may obtain a copy of the License at + + http://www.apache.org/licenses/LICENSE-2.0 + + Unless required by applicable law or agreed to in writing, software + distributed under the License is distributed on an "AS IS" BASIS, + WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + See the License for the specific language governing permissions and + limitations under the License. + */ + + member procedure init(self in out nocopy ut_include, a_expected ut_data_value), + constructor function ut_include(self in out nocopy ut_include, a_expected sys_refcursor) return self as result, + member function get_inclusion_compare return boolean, + overriding member function run_matcher(self in out nocopy ut_include, a_actual ut_data_value) return boolean, + overriding member function failure_message(a_actual ut_data_value) return varchar2 +) +/ diff --git a/source/install.sql b/source/install.sql index 902b45aba..b58fb4e24 100644 --- a/source/install.sql +++ b/source/install.sql @@ -203,6 +203,7 @@ prompt Installing DBMSPLSQL Tables objects into &&ut3_owner schema @@install_component.sql 'expectations/matchers/ut_be_null.tps' @@install_component.sql 'expectations/matchers/ut_be_true.tps' @@install_component.sql 'expectations/matchers/ut_equal.tps' +@@install_component.sql 'expectations/matchers/ut_include.tps' @@install_component.sql 'expectations/matchers/ut_have_count.tps' @@install_component.sql 'expectations/matchers/ut_be_between.tps' @@install_component.sql 'expectations/matchers/ut_be_empty.tps' @@ -241,6 +242,7 @@ prompt Installing DBMSPLSQL Tables objects into &&ut3_owner schema @@install_component.sql 'expectations/matchers/ut_be_null.tpb' @@install_component.sql 'expectations/matchers/ut_be_true.tpb' @@install_component.sql 'expectations/matchers/ut_equal.tpb' +@@install_component.sql 'expectations/matchers/ut_include.tpb' @@install_component.sql 'expectations/matchers/ut_have_count.tpb' @@install_component.sql 'expectations/matchers/ut_be_between.tpb' @@install_component.sql 'expectations/matchers/ut_be_empty.tpb' diff --git a/source/uninstall_objects.sql b/source/uninstall_objects.sql index cf8b3905f..0e059be56 100644 --- a/source/uninstall_objects.sql +++ b/source/uninstall_objects.sql @@ -69,6 +69,8 @@ drop type ut_match force; drop type ut_be_between force; +drop type ut_include force; + drop type ut_equal force; drop type ut_be_true force; From 440670b25396dfd63854cfb7e3a6bbe484c78ef3 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Wed, 10 Oct 2018 18:21:19 +0100 Subject: [PATCH 05/83] Update install --- source/expectations/matchers/ut_equal.tps | 1 + 1 file changed, 1 insertion(+) diff --git a/source/expectations/matchers/ut_equal.tps b/source/expectations/matchers/ut_equal.tps index ce2c9ed92..a2b984c63 100644 --- a/source/expectations/matchers/ut_equal.tps +++ b/source/expectations/matchers/ut_equal.tps @@ -71,3 +71,4 @@ create or replace type ut_equal force under ut_comparison_matcher( overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2 ) not final +/ \ No newline at end of file From a0ee1953c349a8155dd8462d9ae629ebdbf43b47 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 11 Oct 2018 12:17:51 +0100 Subject: [PATCH 06/83] Added tests for include --- .../data_values/ut_compound_data_helper.pkb | 4 +- .../data_values/ut_compound_data_value.tpb | 8 +- .../expectations/test_expectations_cursor.pkb | 143 ++++++++++++++++++ .../expectations/test_expectations_cursor.pks | 24 +++ 4 files changed, 172 insertions(+), 7 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 4193c7f4a..136ab1884 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -176,7 +176,6 @@ create or replace package body ut_compound_data_helper is l_results tt_row_diffs; begin l_column_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath); - /** * Since its unordered search we cannot select max rows from diffs as we miss some comparision records * We will restrict output on higher level of select @@ -600,7 +599,8 @@ create or replace package body ut_compound_data_helper is source_data s where t.data_id = :other_guid and s.data_id = :self_guid - and t.pk_hash = s.pk_hash + and t.pk_hash = s.pk_hash + and t.item_hash != s.item_hash ) ) tmp'; diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index a9c101ade..38fe9ebc4 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -107,7 +107,6 @@ create or replace type body ut_compound_data_value as l_actual := treat(a_other as ut_compound_data_value); dbms_lob.createtemporary(l_result,true); - --diff rows and row elements l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); @@ -115,7 +114,6 @@ create or replace type body ut_compound_data_value as execute immediate 'select count('||case when a_join_by_xpath is not null then 'distinct pk_hash' else '*' end||') from ' || l_ut_owner || '.ut_compound_data_diff_tmp where diff_id = :diff_id' into l_diff_row_count using l_diff_id; - if l_diff_row_count > 0 then l_compare_type := ut_compound_data_helper.compare_type(a_join_by_xpath,a_unordered); l_row_diffs := ut_compound_data_helper.get_rows_diff( @@ -224,7 +222,7 @@ create or replace type body ut_compound_data_value as if not a_other is of (ut_compound_data_value) then raise value_error; end if; - + l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); @@ -264,11 +262,11 @@ create or replace type body ut_compound_data_value as l_diff_id, self.data_id, l_other.data_id, l_other.data_id,self.data_id; - + /*!* * Result OK when is not inclusion matcher and both are the same * Resullt OK when is inclusion matcher and left contains right set - */ + */ if sql%rowcount = 0 and self.elements_count = l_other.elements_count and not(a_inclusion_compare ) then l_result := 0; elsif sql%rowcount = 0 and a_inclusion_compare then diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index d18cef5fb..3cded1aec 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -1986,6 +1986,149 @@ Diff:% ut.expect(l_actual_message).to_be_like(l_expected_message); end; + + procedure cursor_contain is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select owner, object_name,object_type from all_objects where owner = user + order by 1,2,3 asc; + open l_expected for select owner, object_name,object_type from all_objects where owner = user + and rownum < 20; + + --Act + ut3.ut.expect(l_actual).to_include(l_expected); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure cursor_contain_fail is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); + begin + --Arrange + open l_actual for select owner, object_name,object_type from all_objects where owner = user + and rownum < 5; + open l_expected for select owner, object_name,object_type from all_objects where owner = user + and rownum < 10; + + --Act + ut3.ut.expect(l_actual).to_include(l_expected); + --Assert + l_expected_message := q'[%Actual: refcursor [ count = 4 ] was expected to include: refcursor [ count = 9 ] +%Diff: +%Rows: [ 5 differences ] +%Missing: %%% +%Missing: %%% +%Missing: %%% +%Missing: %%% +%Missing: %%%%]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + end; + + procedure cursor_contain_joinby is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select username,user_id from all_users; + open l_expected for select username ,user_id from all_users where rownum < 5; + + --Act + ut3.ut.expect(l_actual).to_include(l_expected).join_by('USERNAME'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + procedure cursor_contain_joinby_fail is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); + begin + --Arrange + open l_actual for select username, user_id from all_users + union all + select 'TEST' username, -600 user_id from dual + order by 1 desc; + open l_expected for select username, user_id from all_users + union all + select 'TEST' username, -601 user_id from dual + order by 1 asc; + + --Act + ut3.ut.expect(l_actual).to_include(l_expected).join_by('USERNAME'); + --Assert + l_expected_message := q'[%Actual: refcursor [ count = % ] was expected to include: refcursor [ count = % ] +%Diff: +%Rows: [ 1 differences ] +%PK TEST - Actual: -600 +%PK TEST - Expected: -601%]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + + end; + + procedure contain_incl_cols_as_list + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 6; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_include(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure contain_join_incl_cols_as_lst + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_include(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('RN'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure contain_join_excl_cols_as_lst + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_include(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('RN'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure contain_excl_cols_as_list + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_include(l_expected).exclude(ut3.ut_varchar2_list('A_COLUMN|//Some_Col')); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; end; / diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index a1cff85d9..15abc5b23 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -316,5 +316,29 @@ create or replace package test_expectations_cursor is --%test(Trying to join on collection element inside record ) procedure compare_rec_coll_as_join; + --%test( Cursor contains data from another cursor) + procedure cursor_contain; + + --%test( Fail cursor contains data from another cursor ) + procedure cursor_contain_fail; + + --%test( Cursor contains data from another cursor with joinby) + procedure cursor_contain_joinby; + + --%test( Fail cursor contains data from another cursor with joinby) + procedure cursor_contain_joinby_fail; + + --%test(Cursor contains data with of columns to include) + procedure contain_incl_cols_as_list; + + --%test(Cursor contains data with of columns to include and join by value) + procedure contain_join_incl_cols_as_lst; + + --%test(Cursor contains data with of columns to exclude and join by value) + procedure contain_join_excl_cols_as_lst; + + --%test(Cursor contains data with of columns to exclude) + procedure contain_excl_cols_as_list; + end; / From 314b9984978b8bcb4bfa246c0731014971a80182 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 11 Oct 2018 12:34:30 +0100 Subject: [PATCH 07/83] Added test for to_contain --- .../expectations/test_expectations_cursor.pkb | 44 +++++++++++++++++++ .../expectations/test_expectations_cursor.pks | 6 +++ 2 files changed, 50 insertions(+) diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 3cded1aec..609edb2ad 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2025,6 +2025,50 @@ Diff:% %Missing: %%% %Missing: %%% %Missing: %%% +%Missing: %%%%]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + end; + + procedure cursor_to_contain is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select owner, object_name,object_type from all_objects where owner = user + order by 1,2,3 asc; + open l_expected for select owner, object_name,object_type from all_objects where owner = user + and rownum < 20; + + --Act + ut3.ut.expect(l_actual).to_contain(l_expected); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure cursor_to_contain_fail is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); + begin + --Arrange + open l_actual for select owner, object_name,object_type from all_objects where owner = user + and rownum < 5; + open l_expected for select owner, object_name,object_type from all_objects where owner = user + and rownum < 10; + + --Act + ut3.ut.expect(l_actual).to_contain(l_expected); + --Assert + l_expected_message := q'[%Actual: refcursor [ count = 4 ] was expected to include: refcursor [ count = 9 ] +%Diff: +%Rows: [ 5 differences ] +%Missing: %%% +%Missing: %%% +%Missing: %%% +%Missing: %%% %Missing: %%%%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index 15abc5b23..4d143abfc 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -322,6 +322,12 @@ create or replace package test_expectations_cursor is --%test( Fail cursor contains data from another cursor ) procedure cursor_contain_fail; + --%test( Cursor contains data from another cursor using second keyword) + procedure cursor_to_contain; + + --%test( Fail cursor contains data from another cursor using second keyword) + procedure cursor_to_contain_fail; + --%test( Cursor contains data from another cursor with joinby) procedure cursor_contain_joinby; From 6193ff3ca604ca54dde2575d0805de5a88fe3361 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 11 Oct 2018 14:04:36 +0100 Subject: [PATCH 08/83] Adding negated matcher --- .../data_values/ut_compound_data_helper.pkb | 5 ----- source/expectations/matchers/ut_include.tpb | 16 ++++++++++++++-- source/expectations/matchers/ut_include.tps | 9 +++++++++ source/expectations/ut_expectation.tpb | 5 ++--- source/expectations/ut_expectation_compound.tpb | 4 ++-- source/expectations/ut_expectation_compound.tps | 2 +- 6 files changed, 28 insertions(+), 13 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 136ab1884..8dac49f55 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -606,11 +606,6 @@ create or replace package body ut_compound_data_helper is tmp'; return l_sql; end; - - function get_inclusion_matcher_not_sql(a_owner in varchar2) return varchar2 is - begin - null; - end; function get_refcursor_matcher_sql(a_owner in varchar2,a_inclusion_matcher boolean := false, a_negated_match boolean := false) return varchar2 is l_sql varchar2(32767); diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index cb6eedcda..2d33a5615 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -36,12 +36,24 @@ create or replace type body ut_include as return true; end; + member function negated return ut_include is + l_result ut_include := self; + begin + l_result.is_negated := ut_utils.boolean_to_int(true); + return l_result; + end; + overriding member function run_matcher(self in out nocopy ut_include, a_actual ut_data_value) return boolean is l_result boolean; begin if self.expected.data_type = a_actual.data_type then - l_result := 0 = treat(self.expected as ut_data_value_refcursor).compare_implementation(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), - true,get_inclusion_compare()); + if nvl(self.is_negated,0) = 0 then + l_result := 0 = treat(self.expected as ut_data_value_refcursor).compare_implementation(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), + true,get_inclusion_compare()); + else + l_result := 0 = treat(self.expected as ut_data_value_refcursor).compare_implementation(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), + true,get_inclusion_compare()); + end if; else l_result := (self as ut_matcher).run_matcher(a_actual); end if; diff --git a/source/expectations/matchers/ut_include.tps b/source/expectations/matchers/ut_include.tps index 2896832be..ca73bd581 100644 --- a/source/expectations/matchers/ut_include.tps +++ b/source/expectations/matchers/ut_include.tps @@ -16,9 +16,18 @@ create or replace type ut_include under ut_equal( limitations under the License. */ + /** + * Due to nature of inclusion compare the not is bit diffrente than standard. + * Result is false when even one element belongs which can cause overlap. + * e.g. set can fail at same time not_include and include. By that we mean + * that false include not necessary mean true not include. + */ + is_negated number(1,0), + member procedure init(self in out nocopy ut_include, a_expected ut_data_value), constructor function ut_include(self in out nocopy ut_include, a_expected sys_refcursor) return self as result, member function get_inclusion_compare return boolean, + member function negated return ut_include, overriding member function run_matcher(self in out nocopy ut_include, a_actual ut_data_value) return boolean, overriding member function failure_message(a_actual ut_data_value) return varchar2 ) diff --git a/source/expectations/ut_expectation.tpb b/source/expectations/ut_expectation.tpb index 0ca9c406b..8db05a3f3 100644 --- a/source/expectations/ut_expectation.tpb +++ b/source/expectations/ut_expectation.tpb @@ -32,7 +32,6 @@ create or replace type body ut_expectation as l_matcher ut_matcher := a_matcher; l_message varchar2(32767); begin - l_expectation_result := l_matcher.run_matcher_negated( self.actual_data ); l_expectation_result := coalesce(l_expectation_result,false); l_message := coalesce( l_matcher.error_message( self.actual_data ), l_matcher.failure_message_when_negated( self.actual_data ) ); @@ -691,12 +690,12 @@ create or replace type body ut_expectation as member procedure not_to_include(self in ut_expectation, a_expected sys_refcursor) is begin - self.not_to( ut_include(a_expected) ); + self.not_to( ut_include(a_expected).negated ); end; member procedure not_to_contain(self in ut_expectation, a_expected sys_refcursor) is begin - self.not_to( ut_include(a_expected) ); + self.not_to( ut_include(a_expected).negated ); end; end; diff --git a/source/expectations/ut_expectation_compound.tpb b/source/expectations/ut_expectation_compound.tpb index cee16bdbd..03021bc6d 100644 --- a/source/expectations/ut_expectation_compound.tpb +++ b/source/expectations/ut_expectation_compound.tpb @@ -92,7 +92,7 @@ create or replace type body ut_expectation_compound as member function not_to_include(a_expected sys_refcursor) return ut_expectation_compound is l_result ut_expectation_compound := self; begin - l_result.matcher := ut_include(a_expected); + l_result.matcher := ut_include(a_expected).negated; l_result.negated := ut_utils.boolean_to_int(true); return l_result; end; @@ -100,7 +100,7 @@ create or replace type body ut_expectation_compound as member function not_to_contain(a_expected sys_refcursor) return ut_expectation_compound is l_result ut_expectation_compound := self; begin - l_result.matcher := ut_include(a_expected); + l_result.matcher := ut_include(a_expected).negated; l_result.negated := ut_utils.boolean_to_int(true); return l_result; end; diff --git a/source/expectations/ut_expectation_compound.tps b/source/expectations/ut_expectation_compound.tps index 15b1874fe..ffeb1c056 100644 --- a/source/expectations/ut_expectation_compound.tps +++ b/source/expectations/ut_expectation_compound.tps @@ -51,4 +51,4 @@ create or replace type ut_expectation_compound under ut_expectation( member procedure join_by(self in ut_expectation_compound, a_columns ut_varchar2_list) ) final -/ \ No newline at end of file +/ From f798e3919fed7dee7aadef54a5084b0d1493c8a6 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 14 Oct 2018 09:19:57 +0100 Subject: [PATCH 09/83] Added tests and negated code --- .../data_values/ut_compound_data_helper.pkb | 30 ++++++- .../data_values/ut_compound_data_value.tpb | 8 +- .../data_values/ut_compound_data_value.tps | 2 +- .../data_values/ut_data_value_refcursor.tpb | 5 +- .../data_values/ut_data_value_refcursor.tps | 3 +- source/expectations/matchers/ut_include.tpb | 18 ++-- source/expectations/matchers/ut_include.tps | 4 +- source/expectations/ut_expectation.tpb | 15 +++- source/expectations/ut_expectation.tps | 1 + .../expectations/ut_expectation_compound.tpb | 58 ++++++++---- .../expectations/test_expectations_cursor.pkb | 89 +++++++++++++++++++ .../expectations/test_expectations_cursor.pks | 18 ++++ 12 files changed, 213 insertions(+), 38 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 8dac49f55..a75807f29 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -607,6 +607,34 @@ create or replace package body ut_compound_data_helper is return l_sql; end; + function get_not_inclusion_matcher_sql(a_owner in varchar2) return varchar2 is + l_sql varchar2(32767); + begin + /* Self set does not contain any values from other set */ + l_sql := 'with source_data as + ( select t.data_id,t.item_hash,row_number() over (partition by t.pk_hash,t.item_hash,t.data_id order by 1,2) duplicate_no, + pk_hash + from ' || a_owner || '.ut_compound_data_tmp t + where data_id = :self_guid or data_id = :other_guid + ) + select distinct :diff_id,tmp.item_hash,tmp.pk_hash,tmp.duplicate_no + from + ( + select act.item_hash,act. duplicate_no,act.pk_hash + from source_data act where act.data_id = :self_guid + and exists ( select 1 + from source_data exp + where exp.data_id = :other_guid + and exp.item_hash = act.item_hash + ) + union all + select null,null,null + from dual where :other_guid = :self_guid + ) + tmp'; + return l_sql; + end; + function get_refcursor_matcher_sql(a_owner in varchar2,a_inclusion_matcher boolean := false, a_negated_match boolean := false) return varchar2 is l_sql varchar2(32767); begin @@ -614,7 +642,7 @@ create or replace package body ut_compound_data_helper is if a_inclusion_matcher and not(a_negated_match) then l_sql := l_sql || get_inclusion_matcher_sql(a_owner); elsif a_inclusion_matcher and a_negated_match then - null; + l_sql := l_sql || get_not_inclusion_matcher_sql(a_owner); elsif not(a_inclusion_matcher) then l_sql := l_sql || get_unordered(a_owner); end if; diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 38fe9ebc4..1f4935aa2 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -193,7 +193,7 @@ create or replace type body ut_compound_data_value as end; member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean , a_inclusion_compare boolean := false ) return integer is + a_unordered boolean , a_inclusion_compare boolean := false, a_is_negated boolean := false ) return integer is l_other ut_compound_data_value; l_ut_owner varchar2(250) := ut_utils.ut_owner; l_column_filter varchar2(32767); @@ -255,14 +255,14 @@ create or replace type body ut_compound_data_value as * SELF is expected. * Due to growing complexity I have moved a dynamic SQL into helper package. */ - l_sql := ut_compound_data_helper.get_refcursor_matcher_sql(l_ut_owner,a_inclusion_compare); - + l_sql := ut_compound_data_helper.get_refcursor_matcher_sql(l_ut_owner,a_inclusion_compare,a_is_negated); + execute immediate l_sql using self.data_id, l_other.data_id, l_diff_id, self.data_id, l_other.data_id, l_other.data_id,self.data_id; - + /*!* * Result OK when is not inclusion matcher and both are the same * Resullt OK when is inclusion matcher and left contains right set diff --git a/source/expectations/data_values/ut_compound_data_value.tps b/source/expectations/data_values/ut_compound_data_value.tps index f1c4e6529..51d88c6f8 100644 --- a/source/expectations/data_values/ut_compound_data_value.tps +++ b/source/expectations/data_values/ut_compound_data_value.tps @@ -45,6 +45,6 @@ create or replace type ut_compound_data_value force under ut_data_value( member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return clob, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2) return integer, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean , a_inclusion_compare boolean := false) return integer + a_unordered boolean , a_inclusion_compare boolean := false, a_is_negated boolean := false) return integer ) not final not instantiable / diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 12bacd70b..f380b86f8 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -221,7 +221,7 @@ create or replace type body ut_data_value_refcursor as end; overriding member function compare_implementation (a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean, a_inclusion_compare boolean := false) return integer is + a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false) return integer is l_result integer := 0; l_other ut_data_value_refcursor; function is_pk_missing (a_pk_missing_tab ut_compound_data_helper.tt_missing_pk) return integer is @@ -251,7 +251,7 @@ create or replace type body ut_data_value_refcursor as if a_unordered then l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, - a_join_by_xpath, a_unordered, a_inclusion_compare); + a_join_by_xpath, a_unordered, a_inclusion_compare, a_is_negated); else l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath); end if; @@ -265,6 +265,5 @@ create or replace type body ut_data_value_refcursor as return self.elements_count = 0; end; - end; / diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 38582224f..36c231887 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -45,8 +45,7 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( overriding member function to_string return varchar2, overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, overriding member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean, a_inclusion_compare boolean := false) return integer, + a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false) return integer, overriding member function is_empty return boolean - ) / diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index 2d33a5615..7439aea3e 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -43,17 +43,17 @@ create or replace type body ut_include as return l_result; end; + member function get_negated return boolean is + begin + return ut_utils.int_to_boolean(nvl(is_negated,0)); + end; + overriding member function run_matcher(self in out nocopy ut_include, a_actual ut_data_value) return boolean is l_result boolean; begin if self.expected.data_type = a_actual.data_type then - if nvl(self.is_negated,0) = 0 then - l_result := 0 = treat(self.expected as ut_data_value_refcursor).compare_implementation(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), - true,get_inclusion_compare()); - else l_result := 0 = treat(self.expected as ut_data_value_refcursor).compare_implementation(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), - true,get_inclusion_compare()); - end if; + true,self.get_inclusion_compare(), self.get_negated()); else l_result := (self as ut_matcher).run_matcher(a_actual); end if; @@ -73,5 +73,11 @@ create or replace type body ut_include as return l_result; end; + overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2 is + l_result varchar2(32767); + begin + return (self as ut_matcher).failure_message_when_negated(a_actual) || ':'|| expected.to_string_report(); + end; + end; / diff --git a/source/expectations/matchers/ut_include.tps b/source/expectations/matchers/ut_include.tps index ca73bd581..6ed32756c 100644 --- a/source/expectations/matchers/ut_include.tps +++ b/source/expectations/matchers/ut_include.tps @@ -28,7 +28,9 @@ create or replace type ut_include under ut_equal( constructor function ut_include(self in out nocopy ut_include, a_expected sys_refcursor) return self as result, member function get_inclusion_compare return boolean, member function negated return ut_include, + member function get_negated return boolean, overriding member function run_matcher(self in out nocopy ut_include, a_actual ut_data_value) return boolean, - overriding member function failure_message(a_actual ut_data_value) return varchar2 + overriding member function failure_message(a_actual ut_data_value) return varchar2, + overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2 ) / diff --git a/source/expectations/ut_expectation.tpb b/source/expectations/ut_expectation.tpb index 8db05a3f3..2b86b0502 100644 --- a/source/expectations/ut_expectation.tpb +++ b/source/expectations/ut_expectation.tpb @@ -38,6 +38,17 @@ create or replace type body ut_expectation as ut_expectation_processor.add_expectation_result( ut_expectation_result( ut_utils.to_test_result( l_expectation_result ), self.description, l_message ) ); end; + member procedure not_include(self in ut_expectation, a_matcher ut_matcher) is + l_expectation_result boolean; + l_matcher ut_matcher := a_matcher; + l_message varchar2(32767); + begin + l_expectation_result := l_matcher.run_matcher( self.actual_data ); + l_expectation_result := coalesce(l_expectation_result,false); + l_message := coalesce( l_matcher.error_message( self.actual_data ), l_matcher.failure_message_when_negated( self.actual_data ) ); + ut_expectation_processor.add_expectation_result( ut_expectation_result( ut_utils.to_test_result( l_expectation_result ), self.description, l_message ) ); + end; + member procedure to_be_null(self in ut_expectation) is begin self.to_( ut_be_null() ); @@ -690,12 +701,12 @@ create or replace type body ut_expectation as member procedure not_to_include(self in ut_expectation, a_expected sys_refcursor) is begin - self.not_to( ut_include(a_expected).negated ); + self.not_include( ut_include(a_expected).negated ); end; member procedure not_to_contain(self in ut_expectation, a_expected sys_refcursor) is begin - self.not_to( ut_include(a_expected).negated ); + self.not_include( ut_include(a_expected).negated ); end; end; diff --git a/source/expectations/ut_expectation.tps b/source/expectations/ut_expectation.tps index 99183d022..80f25e21f 100644 --- a/source/expectations/ut_expectation.tps +++ b/source/expectations/ut_expectation.tps @@ -21,6 +21,7 @@ create or replace type ut_expectation authid current_user as object( --base matcher executors member procedure to_(self in ut_expectation, a_matcher ut_matcher), member procedure not_to(self in ut_expectation, a_matcher ut_matcher), + member procedure not_include(self in ut_expectation, a_matcher ut_matcher), --shortcuts member procedure to_be_null(self in ut_expectation), diff --git a/source/expectations/ut_expectation_compound.tpb b/source/expectations/ut_expectation_compound.tpb index 03021bc6d..9dce4d84e 100644 --- a/source/expectations/ut_expectation_compound.tpb +++ b/source/expectations/ut_expectation_compound.tpb @@ -123,22 +123,30 @@ create or replace type body ut_expectation_compound as member procedure include(self in ut_expectation_compound, a_items varchar2) is begin - if ut_utils.int_to_boolean(negated) then - self.not_to( treat(matcher as ut_equal).include(a_items) ); - else - self.to_( treat(matcher as ut_equal).include(a_items) ); - end if; - end; + if ut_utils.int_to_boolean(negated) then + if (matcher is of (ut_include)) then + self.not_include( treat(matcher as ut_equal).include(a_items) ); + else + self.not_to( treat(matcher as ut_equal).include(a_items) ); + end if; + else + self.to_( treat(matcher as ut_equal).include(a_items) ); + end if; + end; member procedure include(self in ut_expectation_compound, a_items ut_varchar2_list) is begin + if ut_utils.int_to_boolean(negated) then + if (matcher is of (ut_include)) then + self.not_include( treat(matcher as ut_equal).include(a_items) ); + else + self.not_to( treat(matcher as ut_equal).include(a_items) ); + end if; + else + self.to_( treat(matcher as ut_equal).include(a_items) ); + end if; + end; - if ut_utils.int_to_boolean(negated) then - self.not_to( treat(matcher as ut_equal).include(a_items) ); - else - self.to_( treat(matcher as ut_equal).include(a_items) ); - end if; - end; member function exclude(a_items varchar2) return ut_expectation_compound is @@ -160,7 +168,11 @@ create or replace type body ut_expectation_compound as member procedure exclude(self in ut_expectation_compound, a_items varchar2) is begin if ut_utils.int_to_boolean(negated) then - self.not_to( treat(matcher as ut_equal).exclude(a_items) ); + if (matcher is of (ut_include)) then + self.not_include( treat(matcher as ut_equal).exclude(a_items) ); + else + self.not_to( treat(matcher as ut_equal).exclude(a_items) ); + end if; else self.to_( treat(matcher as ut_equal).exclude(a_items) ); end if; @@ -168,9 +180,12 @@ create or replace type body ut_expectation_compound as member procedure exclude(self in ut_expectation_compound, a_items ut_varchar2_list) is begin - if ut_utils.int_to_boolean(negated) then - self.not_to( treat(matcher as ut_equal).exclude(a_items) ); + if (matcher is of (ut_include)) then + self.not_include( treat(matcher as ut_equal).exclude(a_items) ); + else + self.not_to( treat(matcher as ut_equal).exclude(a_items) ); + end if; else self.to_( treat(matcher as ut_equal).exclude(a_items) ); end if; @@ -213,7 +228,11 @@ create or replace type body ut_expectation_compound as member procedure join_by(self in ut_expectation_compound, a_columns varchar2) is begin if ut_utils.int_to_boolean(negated) then - self.not_to( treat(matcher as ut_equal).join_by(a_columns) ); + if (matcher is of (ut_include)) then + self.not_include( treat(matcher as ut_equal).join_by(a_columns) ); + else + self.not_to( treat(matcher as ut_equal).join_by(a_columns) ); + end if; else self.to_( treat(matcher as ut_equal).join_by(a_columns) ); end if; @@ -221,9 +240,12 @@ create or replace type body ut_expectation_compound as member procedure join_by(self in ut_expectation_compound, a_columns ut_varchar2_list) is begin - if ut_utils.int_to_boolean(negated) then - self.not_to( treat(matcher as ut_equal).join_by(a_columns) ); + if (matcher is of (ut_include)) then + self.not_include( treat(matcher as ut_equal).join_by(a_columns) ); + else + self.not_to( treat(matcher as ut_equal).join_by(a_columns) ); + end if; else self.to_( treat(matcher as ut_equal).join_by(a_columns) ); end if; diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 609edb2ad..461f58807 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2174,5 +2174,94 @@ Diff:% --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + + procedure cursor_not_to_contain is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_expected for select 'TEST' username, -600 user_id from dual; + + open l_actual for select username, user_id from all_users + union all + select 'TEST' username, -601 user_id from dual; + + --Act + ut3.ut.expect(l_actual).not_to_contain(l_expected); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure cursor_not_to_include is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_expected for select 'TEST' username, -600 user_id from dual; + + open l_actual for select username, user_id from all_users + union all + select 'TEST' username, -601 user_id from dual; + + --Act + ut3.ut.expect(l_actual).not_to_include(l_expected); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure cursor_not_to_contain_joinby is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select username,user_id from all_users; + open l_expected for select username||'ACT' username ,user_id from all_users where rownum < 5; + + --Act + ut3.ut.expect(l_actual).not_to_contain(l_expected).join_by('USER_ID'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure cursor_not_to_include_joinby is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select username,user_id from all_users; + open l_expected for select username||'ACT' username ,user_id from all_users where rownum < 5; + + --Act + ut3.ut.expect(l_actual).not_to_include(l_expected).join_by('USER_ID'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure not_cont_join_incl_cols_as_lst is + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'b' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_include(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('RN'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure not_cont_join_excl_cols_as_lst is + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'y' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_include(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('RN'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + end; / diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index 4d143abfc..66689717f 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -346,5 +346,23 @@ create or replace package test_expectations_cursor is --%test(Cursor contains data with of columns to exclude) procedure contain_excl_cols_as_list; + --%test( Cursor not to contains data from another cursor) + procedure cursor_not_to_contain; + + --%test( Cursor not to include data from another cursor) + procedure cursor_not_to_include; + + --%test( Cursor not contains data from another cursor with joinby clause) + procedure cursor_not_to_contain_joinby; + + --%test( Cursor not include data from another cursor with joinby clause) + procedure cursor_not_to_include_joinby; + + --%test(Cursor not contains data with of columns to include and join by value) + procedure not_cont_join_incl_cols_as_lst; + + --%test(Cursor not contains data with of columns to exclude and join by value) + procedure not_cont_join_excl_cols_as_lst; + end; / From 86276ec639d072c6100f51ff7c1feb117560917a Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Fri, 19 Oct 2018 19:00:38 +0100 Subject: [PATCH 10/83] Fixing test dependency on NLS settings. Fixing test dependency on global_names (for DB links) Fixing missing privs. Resolves #765 --- .../create_synonyms_and_grants_for_public.sql | 4 +- source/create_user_grants.sql | 4 +- test/api/test_ut_run.pkb | 2 +- .../test_annot_throws_exception.pkb | 40 +++++++++---------- ....pkb => test_before_after_annotations.pkb} | 4 +- ....pks => test_before_after_annotations.pks} | 0 test/core/reporters/test_junit_reporter.pkb | 2 +- .../reporters/test_tfs_junit_reporter.pkb | 2 +- test/install_tests.sql | 4 +- 9 files changed, 31 insertions(+), 31 deletions(-) rename test/core/annotations/{test_before_after_test_annotation.pkb => test_before_after_annotations.pkb} (98%) rename test/core/annotations/{test_before_after_test_annotation.pks => test_before_after_annotations.pks} (100%) diff --git a/source/create_synonyms_and_grants_for_public.sql b/source/create_synonyms_and_grants_for_public.sql index 17452ec0c..1ac5bb9ea 100644 --- a/source/create_synonyms_and_grants_for_public.sql +++ b/source/create_synonyms_and_grants_for_public.sql @@ -76,8 +76,8 @@ grant execute on &&ut3_owner..ut_file_mapping to public; grant execute on &&ut3_owner..ut_file_mapper to public; grant execute on &&ut3_owner..ut_key_value_pairs to public; grant execute on &&ut3_owner..ut_key_value_pair to public; -grant select, insert, delete on &&ut3_owner..ut_compound_data_tmp to public; -grant select, insert, delete on &&ut3_owner..ut_compound_data_diff_tmp to public; +grant select, insert, update, delete on &&ut3_owner..ut_compound_data_tmp to public; +grant select, insert, update, delete on &&ut3_owner..ut_compound_data_diff_tmp to public; grant execute on &&ut3_owner..ut_sonar_test_reporter to public; grant execute on &&ut3_owner..ut_annotations to public; grant execute on &&ut3_owner..ut_annotation to public; diff --git a/source/create_user_grants.sql b/source/create_user_grants.sql index bae0364be..07d9097f3 100644 --- a/source/create_user_grants.sql +++ b/source/create_user_grants.sql @@ -96,8 +96,8 @@ grant execute on &&ut3_owner..ut_file_mapping to &ut3_user; grant execute on &&ut3_owner..ut_file_mapper to &ut3_user; grant execute on &&ut3_owner..ut_key_value_pairs to &ut3_user; grant execute on &&ut3_owner..ut_key_value_pair to &ut3_user; -grant select, insert, delete on &&ut3_owner..ut_compound_data_tmp to &ut3_user; -grant select, insert, delete on &&ut3_owner..ut_compound_data_diff_tmp to &ut3_user; +grant select, insert, update, delete on &&ut3_owner..ut_compound_data_tmp to &ut3_user; +grant select, insert, update, delete on &&ut3_owner..ut_compound_data_diff_tmp to &ut3_user; grant execute on &&ut3_owner..ut_sonar_test_reporter to &ut3_user; grant execute on &&ut3_owner..ut_annotations to &ut3_user; grant execute on &&ut3_owner..ut_annotation to &ut3_user; diff --git a/test/api/test_ut_run.pkb b/test/api/test_ut_run.pkb index 704627ac9..dae7e175a 100644 --- a/test/api/test_ut_run.pkb +++ b/test/api/test_ut_run.pkb @@ -589,7 +589,7 @@ create or replace package body test_ut_run is failing_stateful_test [% sec] (FAILED - 1)% Failures:% 1) failing_stateful_test - ORA-04068: existing state of packages (DB_LOOPBACK) has been discarded + ORA-04068: existing state of packages (DB_LOOPBACK%) has been discarded ORA-04061: existing state of package body "UT3_TESTER.STATEFUL_PACKAGE" has been invalidated ORA-04065: not executed, altered or dropped package body "UT3_TESTER.STATEFUL_PACKAGE"% ORA-06512: at line 6% diff --git a/test/core/annotations/test_annot_throws_exception.pkb b/test/core/annotations/test_annot_throws_exception.pkb index 2c8c3be2c..1ad4f19a5 100644 --- a/test/core/annotations/test_annot_throws_exception.pkb +++ b/test/core/annotations/test_annot_throws_exception.pkb @@ -240,43 +240,43 @@ is procedure throws_same_annotated_except is begin - ut.expect(g_tests_results).to_match('^\s*Throws same annotated exception \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Throws same annotated exception \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('raised_same_exception'); end; procedure throws_one_of_annotated_excpt is begin - ut.expect(g_tests_results).to_match('^\s*Throws one of the listed exceptions \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Throws one of the listed exceptions \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('raised_one_listed_exception'); end; procedure throws_with_leading_zero is begin - ut.expect(g_tests_results).to_match('^\s*Leading zero is ignored in exception list \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Leading zero is ignored in exception list \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('leading_0_exception_no'); end; procedure throws_diff_annotated_except is begin - ut.expect(g_tests_results).to_match('^\s*Throws diff exception \[[\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Throws diff exception \[[,\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); ut.expect(g_tests_results).to_match('raised_diff_exception\s+Actual: -20143 was expected to equal: -20144\s+ORA-20143: Test error\s+ORA-06512: at "UT3_TESTER.ANNOTATED_PACKAGE_WITH_THROWS"'); end; procedure throws_empty is begin - ut.expect(g_tests_results).to_match('^\s*Throws empty \[[\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Throws empty \[[,\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); ut.expect(g_tests_results).to_match('empty_throws\s*ORA-20143: Test error\s*ORA-06512: at "UT3_TESTER.ANNOTATED_PACKAGE_WITH_THROWS"'); end; procedure bad_paramters_with_except is begin - ut.expect(g_tests_results).to_match('^\s*Ignores annotation and fails when exception was thrown \[[\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Ignores annotation and fails when exception was thrown \[[,\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); ut.expect(g_tests_results).to_match('bad_paramters_with_except\s*ORA-20143: Test error\s*ORA-06512: at "UT3_TESTER.ANNOTATED_PACKAGE_WITH_THROWS"'); end; procedure bad_paramters_without_except is begin - ut.expect(g_tests_results).to_match('^\s*Ignores annotation and succeeds when no exception thrown \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Ignores annotation and succeeds when no exception thrown \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('bad_paramters_without_except'); end; @@ -288,79 +288,79 @@ is procedure nothing_thrown is begin - ut.expect(g_tests_results).to_match('^\s*Gives failure when a exception is expected and nothing is thrown \[[\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Gives failure when a exception is expected and nothing is thrown \[[,\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); ut.expect(g_tests_results).to_match('nothing_thrown\s*Expected one of exceptions \(-20459, -20136, -20145\) but nothing was raised.'); end; procedure single_exc_const_pkg is begin - ut.expect(g_tests_results).to_match('^\s*Single exception defined as a constant number in package \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Single exception defined as a constant number in package \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('single_exc_const_pkg'); end; procedure list_of_exc_constant is begin - ut.expect(g_tests_results).to_match('^\s*Gives success when one of annotated exception using constant is thrown \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Gives success when one of annotated exception using constant is thrown \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('list_of_exc_constant'); end; procedure fail_not_match_exc is begin - ut.expect(g_tests_results).to_match('^\s*Gives failure when the raised exception is different that the annotated one using variable \[[\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Gives failure when the raised exception is different that the annotated one using variable \[[,\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); ut.expect(g_tests_results).to_match('fail_not_match_exc\s+Actual: -1403 was expected to equal: -20204\s+ORA-01403: no data found\s+ORA-06512: at "UT3_TESTER.ANNOTATED_PACKAGE_WITH_THROWS"'); end; procedure mixed_exc_list is begin - ut.expect(g_tests_results).to_match('^\s*Success when one of exception from mixed list of number and constant is thrown \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Success when one of exception from mixed list of number and constant is thrown \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('mixed_exc_list'); end; procedure mixed_list_notexi is begin - ut.expect(g_tests_results).to_match('^\s*Success when match exception even if other variable on list dont exists \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Success when match exception even if other variable on list dont exists \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('mixed_list_notexi'); end; procedure named_exc_pragma is begin - ut.expect(g_tests_results).to_match('^\s*Success resolve and match named exception defined in pragma exception init \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Success resolve and match named exception defined in pragma exception init \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('mixed_list_notexi'); end; procedure named_exc_ora is begin - ut.expect(g_tests_results).to_match('^\s*Success resolve and match oracle named exception \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Success resolve and match oracle named exception \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('named_exc_ora'); end; procedure named_exc_ora_dup_ind is begin - ut.expect(g_tests_results).to_match('^\s*Success resolve and match oracle named exception dup val index \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Success resolve and match oracle named exception dup val index \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('named_exc_ora_dup_ind'); end; procedure nodata_exc_ora is begin - ut.expect(g_tests_results).to_match('^\s*Success map no data 100 to -1403 \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Success map no data 100 to -1403 \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('nodata_exc_ora'); end; procedure defined_varchar_exc is begin - ut.expect(g_tests_results).to_match('^\s*Success for exception defined as varchar \[[\.0-9]+ sec\]\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Success for exception defined as varchar \[[,\.0-9]+ sec\]\s*$','m'); ut.expect(g_tests_results).not_to_match('defined_varchar_exc'); end; procedure non_existing_const is begin - ut.expect(g_tests_results).to_match('^\s*Non existing constant exception \[[\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Non existing constant exception \[[,\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); ut.expect(g_tests_results).to_match('non_existing_const\s*ORA-20143: Test error\s*ORA-06512: at "UT3_TESTER.ANNOTATED_PACKAGE_WITH_THROWS"'); end; procedure bad_exc_const is begin - ut.expect(g_tests_results).to_match('^\s*Bad exception constant \[[\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); + ut.expect(g_tests_results).to_match('^\s*Bad exception constant \[[,\.0-9]+ sec\] \(FAILED - [0-9]+\)\s*$','m'); ut.expect(g_tests_results).to_match('bad_exc_const\s*ORA-20143: Test error\s*ORA-06512: at "UT3_TESTER.ANNOTATED_PACKAGE_WITH_THROWS"'); end; diff --git a/test/core/annotations/test_before_after_test_annotation.pkb b/test/core/annotations/test_before_after_annotations.pkb similarity index 98% rename from test/core/annotations/test_before_after_test_annotation.pkb rename to test/core/annotations/test_before_after_annotations.pkb index 06871a335..0aa9f5c39 100644 --- a/test/core/annotations/test_before_after_test_annotation.pkb +++ b/test/core/annotations/test_before_after_annotations.pkb @@ -277,7 +277,7 @@ create or replace package body test_before_after_annotations is ut.expect(l_actual).to_be_empty; ut.expect(g_tests_results).to_match( - '^\s*Stops execution at first non-existing Beforetest procedure and marks test as errored \[[\.0-9]+ sec\] \(FAILED - 1\)\s*$' + '^\s*Stops execution at first non-existing Beforetest procedure and marks test as errored \[[,\.0-9]+ sec\] \(FAILED - 1\)\s*$' ,'m' ); ut.expect(g_tests_results).to_match( @@ -297,7 +297,7 @@ create or replace package body test_before_after_annotations is ut.expect(l_actual).to_be_empty; ut.expect(g_tests_results).to_match( - '^\s*Stops execution at first non-existing Beforetest procedure and marks test as errored \[[\.0-9]+ sec\] \(FAILED - 1\)\s*$' + '^\s*Stops execution at first non-existing Beforetest procedure and marks test as errored \[[,\.0-9]+ sec\] \(FAILED - 1\)\s*$' ,'m' ); ut.expect(g_tests_results).to_match( diff --git a/test/core/annotations/test_before_after_test_annotation.pks b/test/core/annotations/test_before_after_annotations.pks similarity index 100% rename from test/core/annotations/test_before_after_test_annotation.pks rename to test/core/annotations/test_before_after_annotations.pks diff --git a/test/core/reporters/test_junit_reporter.pkb b/test/core/reporters/test_junit_reporter.pkb index 6cd67b8a3..e0a7ea00d 100644 --- a/test/core/reporters/test_junit_reporter.pkb +++ b/test/core/reporters/test_junit_reporter.pkb @@ -166,7 +166,7 @@ create or replace package body test_junit_reporter as l_nls_numeric_characters varchar2(30); begin --Arrange - select nsp.value into l_nls_numeric_characters + select replace(nsp.value,'''','''''') into l_nls_numeric_characters from nls_session_parameters nsp where parameter = 'NLS_NUMERIC_CHARACTERS'; execute immediate q'[alter session set NLS_NUMERIC_CHARACTERS=', ']'; diff --git a/test/core/reporters/test_tfs_junit_reporter.pkb b/test/core/reporters/test_tfs_junit_reporter.pkb index bd09b8682..122c665e3 100644 --- a/test/core/reporters/test_tfs_junit_reporter.pkb +++ b/test/core/reporters/test_tfs_junit_reporter.pkb @@ -149,7 +149,7 @@ create or replace package body test_tfs_junit_reporter as l_nls_numeric_characters varchar2(30); begin --Arrange - select nsp.value into l_nls_numeric_characters + select replace(nsp.value,'''','''''') into l_nls_numeric_characters from nls_session_parameters nsp where parameter = 'NLS_NUMERIC_CHARACTERS'; execute immediate q'[alter session set NLS_NUMERIC_CHARACTERS=', ']'; diff --git a/test/install_tests.sql b/test/install_tests.sql index 2aa60692c..2f1292b74 100644 --- a/test/install_tests.sql +++ b/test/install_tests.sql @@ -23,7 +23,7 @@ alter session set plsql_optimize_level=0; @@core/test_ut_test.pks @@core/annotations/test_annotation_parser.pks @@core/annotations/test_annotation_manager.pks -@@core/annotations/test_before_after_test_annotation.pks +@@core/annotations/test_before_after_annotations.pks @@core/expectations/test_expectation_processor.pks @@core/expectations/test_matchers.pks @@core/test_output_buffer.pks @@ -74,7 +74,7 @@ set define off @@core/annotations/test_annotation_manager.pkb @@core/expectations/test_expectation_processor.pkb @@core/expectations/test_matchers.pkb -@@core/annotations/test_before_after_test_annotation.pkb +@@core/annotations/test_before_after_annotations.pkb @@core/test_output_buffer.pkb @@core/test_file_mapper.pkb @@core/test_suite_manager.pkb From 7b037d47cc92102df65546314e37c02fd98920e3 Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Fri, 19 Oct 2018 19:07:08 +0100 Subject: [PATCH 11/83] Adding fix to avoid running sonar-scanner on external pull-requests. --- .travis.yml | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.travis.yml b/.travis.yml index a6aecb53c..58aa254e8 100644 --- a/.travis.yml +++ b/.travis.yml @@ -95,7 +95,7 @@ before_script: script: - if [[ ! $TRAVIS_TAG ]]; then bash test/install_and_run_tests.sh; fi - if [[ ! $TRAVIS_TAG ]]; then bash .travis/validate_report_files.sh; fi - - if [[ ! $TRAVIS_TAG ]] && [ "${TRAVIS_REPO_SLUG}" = "${UTPLSQL_REPO}" ]; then bash .travis/run_sonar_scanner.sh; fi + - if [[ ! $TRAVIS_TAG ]] && [ "${TRAVIS_REPO_SLUG}" = "${UTPLSQL_REPO}" ] && [ "${TRAVIS_PULL_REQUEST_SLUG}" = "${TRAVIS_REPO_SLUG}" ]; then bash .travis/run_sonar_scanner.sh; fi - if [[ ! $TRAVIS_TAG ]]; then bash .travis/coveralls_uploader.sh; fi notifications: From b2f1b96c186203f697f87b27c679a0b8cdd8dbc1 Mon Sep 17 00:00:00 2001 From: Travis CI Date: Fri, 19 Oct 2018 20:03:12 +0000 Subject: [PATCH 12/83] Updated project version after build [skip ci] --- source/core/ut_utils.pks | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/source/core/ut_utils.pks b/source/core/ut_utils.pks index a96253c58..a4388c523 100644 --- a/source/core/ut_utils.pks +++ b/source/core/ut_utils.pks @@ -21,7 +21,7 @@ create or replace package ut_utils authid definer is * */ - gc_version constant varchar2(50) := 'v3.1.3.2251-develop'; + gc_version constant varchar2(50) := 'v3.1.3.2276-develop'; /* Constants: Event names */ subtype t_event_name is varchar2(30); From 80ea7d79da781938c8d1a76606d36d2ad199f962 Mon Sep 17 00:00:00 2001 From: Philipp Salvisberg Date: Fri, 19 Oct 2018 17:57:26 +0200 Subject: [PATCH 13/83] Change CLI version to 3.1.0. It is a requirement to test the current develp branch --- development/template.env.sh | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/development/template.env.sh b/development/template.env.sh index 1e90aaed3..94004c89d 100755 --- a/development/template.env.sh +++ b/development/template.env.sh @@ -4,7 +4,7 @@ export SQLCLI=sql # For sqlcl client #export SQLCLI=sqlplus # For sqlplus client export CONNECTION_STR=127.0.0.1:1521/xe # Adjust the connect string export ORACLE_PWD=oracle # Adjust your local SYS password -export UTPLSQL_CLI_VERSION="3.0.4" +export UTPLSQL_CLI_VERSION="3.1.0" export SELFTESTING_BRANCH=develop export UTPLSQL_DIR="utPLSQL_latest_release" From 3d3a2e82a014ef3afa9c401f8ec8d240744fa485 Mon Sep 17 00:00:00 2001 From: Philipp Salvisberg Date: Fri, 19 Oct 2018 17:58:12 +0200 Subject: [PATCH 14/83] ignore temporary files created by actions described in CONTRIBUTING.md --- .gitignore | 10 ++++++++++ 1 file changed, 10 insertions(+) diff --git a/.gitignore b/.gitignore index 13452754f..197d0f5e9 100644 --- a/.gitignore +++ b/.gitignore @@ -16,3 +16,13 @@ utPLSQL_latest_release/ utPLSQL-cli/ development/env.sh *.log + +# exclusions based on artifacts created via actions documented in CONTRIBUTING.md +test/dummy.sql +coverage.html_assets/ +coverage.html +coverage.json +coverage.xml +tfs_test_results.xml +junit_test_results.xml +test_results.xml From 7170cda123f0837b2a3a7f0e062f4505b085fa88 Mon Sep 17 00:00:00 2001 From: Travis CI Date: Fri, 19 Oct 2018 23:12:12 +0000 Subject: [PATCH 15/83] Updated project version after build [skip ci] --- source/core/ut_utils.pks | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/source/core/ut_utils.pks b/source/core/ut_utils.pks index a4388c523..fbf9a73ae 100644 --- a/source/core/ut_utils.pks +++ b/source/core/ut_utils.pks @@ -21,7 +21,7 @@ create or replace package ut_utils authid definer is * */ - gc_version constant varchar2(50) := 'v3.1.3.2276-develop'; + gc_version constant varchar2(50) := 'v3.1.3.2278-develop'; /* Constants: Event names */ subtype t_event_name is varchar2(30); From 59b1ead8ce22c56686fa3214addcb56cef965638 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 20 Oct 2018 22:20:05 +0100 Subject: [PATCH 16/83] fix to unordered. Due to missing duplicate_no in populated table the data results been skewed. --- .../data_values/ut_compound_data_helper.pkb | 5 +-- .../data_values/ut_compound_data_value.tpb | 11 ++++++- .../expectations/test_expectations_cursor.pkb | 32 +++++++++++++++++++ .../expectations/test_expectations_cursor.pks | 8 ++--- 4 files changed, 49 insertions(+), 7 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index a75807f29..51614d56e 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -372,8 +372,7 @@ create or replace package body ut_compound_data_helper is /** * Since its unordered search we cannot select max rows from diffs as we miss some comparision records * We will restrict output on higher level of select - */ - + */ execute immediate q'[with diff_info as (select item_hash,duplicate_no from ut_compound_data_diff_tmp ucdc where diff_id = :diff_guid) select duplicate_no, @@ -402,6 +401,7 @@ create or replace package body ut_compound_data_helper is diff_info i where ucd.data_id = :self_guid and ucd.item_hash = i.item_hash + and ucd.duplicate_no = i.duplicate_no ) r, table( xmlsequence( extract(r.item_data,'/*') ) ) ucd ) ucd @@ -416,6 +416,7 @@ create or replace package body ut_compound_data_helper is diff_info i where ucd.data_id = :other_guid and ucd.item_hash = i.item_hash + and ucd.duplicate_no = i.duplicate_no ) r, table( xmlsequence( extract(r.item_data,'/*') ) ) ucd ) ucd diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 1f4935aa2..d12817cee 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -234,6 +234,13 @@ create or replace type body ut_compound_data_value as **/ execute immediate 'merge into ' || l_ut_owner || '.ut_compound_data_tmp tgt using ( + select ucd_out.item_hash, + ucd_out.pk_hash, + ucd_out.item_no, + ucd_out.data_id, + row_number() over (partition by ucd_out.pk_hash,ucd_out.item_hash,ucd_out.data_id order by 1,2) duplicate_no + from + ( select '||l_ut_owner ||'.ut_compound_data_helper.get_hash(ucd.item_data.getclobval()) item_hash, pk_hash, ucd.item_no, ucd.data_id from @@ -242,11 +249,13 @@ create or replace type body ut_compound_data_value as from ' || l_ut_owner || q'[.ut_compound_data_tmp ucd where data_id = :self_guid or data_id = :other_guid ) ucd + )ucd_out ) src on (tgt.item_no = src.item_no and tgt.data_id = src.data_id) when matched then update set tgt.item_hash = src.item_hash, - tgt.pk_hash = src.pk_hash ]' + tgt.pk_hash = src.pk_hash, + tgt.duplicate_no = src.duplicate_no]' using a_exclude_xpath, a_include_xpath,a_join_by_xpath,self.data_id, l_other.data_id; /*!* diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 461f58807..cede6a7c0 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -1987,6 +1987,38 @@ Diff:% end; + procedure unordered_fix_764 is + l_actual sys_refcursor; + l_expected sys_refcursor; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); + begin + open l_expected for + select 'Table' as name from dual + union all + select 'Desk' as name from dual + union all + select 'Table' as name from dual; + + open l_actual for + select 'Desk' as name from dual + union all + select 'Table' as name from dual; + + --Assert + ut3.ut.expect( l_actual ).to_equal( l_expected ).unordered(); + + --Assert + l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 3 ] +%Diff: +%Rows: [ 1 differences ] +%Missing: Table%]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + + end; + procedure cursor_contain is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index 66689717f..9085bd2fc 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -315,10 +315,10 @@ create or replace package test_expectations_cursor is --%test(Trying to join on collection element inside record ) procedure compare_rec_coll_as_join; - - --%test( Cursor contains data from another cursor) - procedure cursor_contain; - + + --%test( Unordered fix for issues with duplicate no : #764 ) + procedure unordered_fix_764; + --%test( Fail cursor contains data from another cursor ) procedure cursor_contain_fail; From 4d2a890e823c6db919f551512e7c9754f73e93fb Mon Sep 17 00:00:00 2001 From: Travis CI Date: Sat, 20 Oct 2018 23:27:34 +0000 Subject: [PATCH 17/83] Updated project version after build [skip ci] --- source/core/ut_utils.pks | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/source/core/ut_utils.pks b/source/core/ut_utils.pks index fbf9a73ae..a42cda124 100644 --- a/source/core/ut_utils.pks +++ b/source/core/ut_utils.pks @@ -21,7 +21,7 @@ create or replace package ut_utils authid definer is * */ - gc_version constant varchar2(50) := 'v3.1.3.2278-develop'; + gc_version constant varchar2(50) := 'v3.1.3.2284-develop'; /* Constants: Event names */ subtype t_event_name is varchar2(30); From 29e1bf75e35ce4822025d643a4479a6811a03d55 Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Sat, 20 Oct 2018 22:41:01 +0100 Subject: [PATCH 18/83] Moving uninstall tests to child job no 2 - (12.1) as it is now fastest build. --- .travis/install.sh | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/.travis/install.sh b/.travis/install.sh index 7b799eaa0..528b44f20 100644 --- a/.travis/install.sh +++ b/.travis/install.sh @@ -13,8 +13,8 @@ alter session set plsql_optimize_level=0; @install_headless.sql $UT3_OWNER $UT3_OWNER_PASSWORD SQL -#Run this step only on first job slave (11.2 - at it's fastest) -if [[ "${TRAVIS_JOB_NUMBER}" =~ \.1$ ]]; then +#Run this step only on second child job (12.1 - at it's fastest) +if [[ "${TRAVIS_JOB_NUMBER}" =~ \.2$ ]]; then #check code-style for errors time "$SQLCLI" $UT3_OWNER/$UT3_OWNER_PASSWORD@//$CONNECTION_STR @../development/utplsql_style_check.sql From 45448acf3958fff7b9ce7c13095a94f347d953c2 Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Sun, 21 Oct 2018 01:54:35 +0100 Subject: [PATCH 19/83] Disabling compilation with PLSQL compiler warnings. --- .travis/install.sh | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/.travis/install.sh b/.travis/install.sh index 528b44f20..e37cfa35f 100644 --- a/.travis/install.sh +++ b/.travis/install.sh @@ -8,7 +8,7 @@ time "$SQLCLI" sys/$ORACLE_PWD@//$CONNECTION_STR AS SYSDBA <<-SQL set feedback off set verify off -alter session set plsql_warnings = 'ENABLE:ALL', 'DISABLE:(5004,5018,6000,6001,6003,6009,6010,7206)'; +--alter session set plsql_warnings = 'ENABLE:ALL', 'DISABLE:(5004,5018,6000,6001,6003,6009,6010,7206)'; alter session set plsql_optimize_level=0; @install_headless.sql $UT3_OWNER $UT3_OWNER_PASSWORD SQL From add5ed808d83b31d2995392d24ec22fc763e9beb Mon Sep 17 00:00:00 2001 From: Travis CI Date: Sun, 21 Oct 2018 01:24:18 +0000 Subject: [PATCH 20/83] Updated project version after build [skip ci] --- source/core/ut_utils.pks | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/source/core/ut_utils.pks b/source/core/ut_utils.pks index a42cda124..5623efa9b 100644 --- a/source/core/ut_utils.pks +++ b/source/core/ut_utils.pks @@ -21,7 +21,7 @@ create or replace package ut_utils authid definer is * */ - gc_version constant varchar2(50) := 'v3.1.3.2284-develop'; + gc_version constant varchar2(50) := 'v3.1.3.2297-develop'; /* Constants: Event names */ subtype t_event_name is varchar2(30); From f39b96a7392ef289787454fc9ec75da1af48c401 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 21 Oct 2018 19:56:32 +0100 Subject: [PATCH 21/83] Update not to include --- .../data_values/ut_compound_data_helper.pkb | 6 +- source/expectations/ut_expectation.tpb | 23 ++- source/expectations/ut_expectation.tps | 3 +- .../expectations/ut_expectation_compound.tpb | 36 +---- .../expectations/test_expectations_cursor.pkb | 146 ++++++++++++++++-- .../expectations/test_expectations_cursor.pks | 40 ++++- 6 files changed, 187 insertions(+), 67 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 51614d56e..fc571e372 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -544,7 +544,7 @@ create or replace package body ut_compound_data_helper is l_sql varchar2(32767); begin l_sql := 'with source_data as - ( select t.data_id,t.item_hash,row_number() over (partition by t.pk_hash,t.item_hash,t.data_id order by 1,2) duplicate_no, + ( select t.data_id,t.item_hash,t.duplicate_no, pk_hash from ' || a_owner || '.ut_compound_data_tmp t where data_id = :self_guid or data_id = :other_guid @@ -577,7 +577,7 @@ create or replace package body ut_compound_data_helper is l_sql varchar2(32767); begin l_sql := 'with source_data as - ( select t.data_id,t.item_hash,row_number() over (partition by t.pk_hash,t.item_hash,t.data_id order by 1,2) duplicate_no, + ( select t.data_id,t.item_hash,t.duplicate_no, pk_hash from ' || a_owner || '.ut_compound_data_tmp t where data_id = :self_guid or data_id = :other_guid @@ -613,7 +613,7 @@ create or replace package body ut_compound_data_helper is begin /* Self set does not contain any values from other set */ l_sql := 'with source_data as - ( select t.data_id,t.item_hash,row_number() over (partition by t.pk_hash,t.item_hash,t.data_id order by 1,2) duplicate_no, + ( select t.data_id,t.item_hash,t.duplicate_no, pk_hash from ' || a_owner || '.ut_compound_data_tmp t where data_id = :self_guid or data_id = :other_guid diff --git a/source/expectations/ut_expectation.tpb b/source/expectations/ut_expectation.tpb index 2b86b0502..2ad402459 100644 --- a/source/expectations/ut_expectation.tpb +++ b/source/expectations/ut_expectation.tpb @@ -32,18 +32,13 @@ create or replace type body ut_expectation as l_matcher ut_matcher := a_matcher; l_message varchar2(32767); begin - l_expectation_result := l_matcher.run_matcher_negated( self.actual_data ); - l_expectation_result := coalesce(l_expectation_result,false); - l_message := coalesce( l_matcher.error_message( self.actual_data ), l_matcher.failure_message_when_negated( self.actual_data ) ); - ut_expectation_processor.add_expectation_result( ut_expectation_result( ut_utils.to_test_result( l_expectation_result ), self.description, l_message ) ); - end; - - member procedure not_include(self in ut_expectation, a_matcher ut_matcher) is - l_expectation_result boolean; - l_matcher ut_matcher := a_matcher; - l_message varchar2(32767); - begin - l_expectation_result := l_matcher.run_matcher( self.actual_data ); + --Negated matcher for include option. + if (l_matcher is of (ut_include)) then + l_expectation_result := l_matcher.run_matcher( self.actual_data ); + else + l_expectation_result := l_matcher.run_matcher_negated( self.actual_data ); + end if; + l_expectation_result := coalesce(l_expectation_result,false); l_message := coalesce( l_matcher.error_message( self.actual_data ), l_matcher.failure_message_when_negated( self.actual_data ) ); ut_expectation_processor.add_expectation_result( ut_expectation_result( ut_utils.to_test_result( l_expectation_result ), self.description, l_message ) ); @@ -701,12 +696,12 @@ create or replace type body ut_expectation as member procedure not_to_include(self in ut_expectation, a_expected sys_refcursor) is begin - self.not_include( ut_include(a_expected).negated ); + self.not_to( ut_include(a_expected).negated ); end; member procedure not_to_contain(self in ut_expectation, a_expected sys_refcursor) is begin - self.not_include( ut_include(a_expected).negated ); + self.not_to( ut_include(a_expected).negated ); end; end; diff --git a/source/expectations/ut_expectation.tps b/source/expectations/ut_expectation.tps index 80f25e21f..215a0e00a 100644 --- a/source/expectations/ut_expectation.tps +++ b/source/expectations/ut_expectation.tps @@ -21,8 +21,7 @@ create or replace type ut_expectation authid current_user as object( --base matcher executors member procedure to_(self in ut_expectation, a_matcher ut_matcher), member procedure not_to(self in ut_expectation, a_matcher ut_matcher), - member procedure not_include(self in ut_expectation, a_matcher ut_matcher), - + --shortcuts member procedure to_be_null(self in ut_expectation), member procedure to_be_not_null(self in ut_expectation), diff --git a/source/expectations/ut_expectation_compound.tpb b/source/expectations/ut_expectation_compound.tpb index 9dce4d84e..b34b97c85 100644 --- a/source/expectations/ut_expectation_compound.tpb +++ b/source/expectations/ut_expectation_compound.tpb @@ -124,11 +124,7 @@ create or replace type body ut_expectation_compound as member procedure include(self in ut_expectation_compound, a_items varchar2) is begin if ut_utils.int_to_boolean(negated) then - if (matcher is of (ut_include)) then - self.not_include( treat(matcher as ut_equal).include(a_items) ); - else - self.not_to( treat(matcher as ut_equal).include(a_items) ); - end if; + self.not_to( treat(matcher as ut_equal).include(a_items) ); else self.to_( treat(matcher as ut_equal).include(a_items) ); end if; @@ -137,11 +133,7 @@ create or replace type body ut_expectation_compound as member procedure include(self in ut_expectation_compound, a_items ut_varchar2_list) is begin if ut_utils.int_to_boolean(negated) then - if (matcher is of (ut_include)) then - self.not_include( treat(matcher as ut_equal).include(a_items) ); - else - self.not_to( treat(matcher as ut_equal).include(a_items) ); - end if; + self.not_to( treat(matcher as ut_equal).include(a_items) ); else self.to_( treat(matcher as ut_equal).include(a_items) ); end if; @@ -168,11 +160,7 @@ create or replace type body ut_expectation_compound as member procedure exclude(self in ut_expectation_compound, a_items varchar2) is begin if ut_utils.int_to_boolean(negated) then - if (matcher is of (ut_include)) then - self.not_include( treat(matcher as ut_equal).exclude(a_items) ); - else - self.not_to( treat(matcher as ut_equal).exclude(a_items) ); - end if; + self.not_to( treat(matcher as ut_equal).exclude(a_items) ); else self.to_( treat(matcher as ut_equal).exclude(a_items) ); end if; @@ -181,11 +169,7 @@ create or replace type body ut_expectation_compound as member procedure exclude(self in ut_expectation_compound, a_items ut_varchar2_list) is begin if ut_utils.int_to_boolean(negated) then - if (matcher is of (ut_include)) then - self.not_include( treat(matcher as ut_equal).exclude(a_items) ); - else - self.not_to( treat(matcher as ut_equal).exclude(a_items) ); - end if; + self.not_to( treat(matcher as ut_equal).exclude(a_items) ); else self.to_( treat(matcher as ut_equal).exclude(a_items) ); end if; @@ -228,11 +212,7 @@ create or replace type body ut_expectation_compound as member procedure join_by(self in ut_expectation_compound, a_columns varchar2) is begin if ut_utils.int_to_boolean(negated) then - if (matcher is of (ut_include)) then - self.not_include( treat(matcher as ut_equal).join_by(a_columns) ); - else - self.not_to( treat(matcher as ut_equal).join_by(a_columns) ); - end if; + self.not_to( treat(matcher as ut_equal).join_by(a_columns) ); else self.to_( treat(matcher as ut_equal).join_by(a_columns) ); end if; @@ -241,11 +221,7 @@ create or replace type body ut_expectation_compound as member procedure join_by(self in ut_expectation_compound, a_columns ut_varchar2_list) is begin if ut_utils.int_to_boolean(negated) then - if (matcher is of (ut_include)) then - self.not_include( treat(matcher as ut_equal).join_by(a_columns) ); - else - self.not_to( treat(matcher as ut_equal).join_by(a_columns) ); - end if; + self.not_to( treat(matcher as ut_equal).join_by(a_columns) ); else self.to_( treat(matcher as ut_equal).join_by(a_columns) ); end if; diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index cede6a7c0..3778bd93f 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2019,7 +2019,7 @@ Diff:% end; - procedure cursor_contain is + procedure cursor_to_include is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; begin @@ -2035,7 +2035,7 @@ Diff:% ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; - procedure cursor_contain_fail is + procedure cursor_to_include_fail is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; l_expected_message varchar2(32767); @@ -2107,7 +2107,7 @@ Diff:% ut.expect(l_actual_message).to_be_like(l_expected_message); end; - procedure cursor_contain_joinby is + procedure cursor_to_include_joinby is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; begin @@ -2121,7 +2121,7 @@ Diff:% ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; - procedure cursor_contain_joinby_fail is + procedure cursor_to_include_joinby_fail is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; l_expected_message varchar2(32767); @@ -2151,7 +2151,51 @@ Diff:% end; - procedure contain_incl_cols_as_list + procedure cursor_contain_joinby is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select username,user_id from all_users; + open l_expected for select username ,user_id from all_users where rownum < 5; + + --Act + ut3.ut.expect(l_actual).to_contain(l_expected).join_by('USERNAME'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure cursor_contain_joinby_fail is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); + begin + --Arrange + open l_actual for select username, user_id from all_users + union all + select 'TEST' username, -600 user_id from dual + order by 1 desc; + open l_expected for select username, user_id from all_users + union all + select 'TEST' username, -601 user_id from dual + order by 1 asc; + + --Act + ut3.ut.expect(l_actual).to_contain(l_expected).join_by('USERNAME'); + --Assert + l_expected_message := q'[%Actual: refcursor [ count = % ] was expected to include: refcursor [ count = % ] +%Diff: +%Rows: [ 1 differences ] +%PK TEST - Actual: -600 +%PK TEST - Expected: -601%]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + + end; + + procedure to_include_incl_cols_as_list as l_actual sys_refcursor; l_expected sys_refcursor; @@ -2164,8 +2208,22 @@ Diff:% --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + + procedure to_contain_cont_cols_as_list + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 6; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_contain(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; - procedure contain_join_incl_cols_as_lst + procedure to_inc_join_incl_cols_as_lst as l_actual sys_refcursor; l_expected sys_refcursor; @@ -2179,7 +2237,21 @@ Diff:% ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; - procedure contain_join_excl_cols_as_lst + procedure to_cont_join_incl_cols_as_lst + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_contain(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('RN'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure include_join_excl_cols_as_lst as l_actual sys_refcursor; l_expected sys_refcursor; @@ -2193,7 +2265,21 @@ Diff:% ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; - procedure contain_excl_cols_as_list + procedure contain_join_excl_cols_as_lst + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_contain(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('RN'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure include_excl_cols_as_list as l_actual sys_refcursor; l_expected sys_refcursor; @@ -2205,6 +2291,20 @@ Diff:% ut3.ut.expect(l_actual).to_include(l_expected).exclude(ut3.ut_varchar2_list('A_COLUMN|//Some_Col')); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure contain_excl_cols_as_list + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).to_contain(l_expected).exclude(ut3.ut_varchar2_list('A_COLUMN|//Some_Col')); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; procedure cursor_not_to_contain is @@ -2268,6 +2368,19 @@ Diff:% --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + + procedure not_inc_join_incl_cols_as_lst is + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'b' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).not_to_include(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('RN'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; procedure not_cont_join_incl_cols_as_lst is l_actual sys_refcursor; @@ -2277,7 +2390,20 @@ Diff:% open l_actual for select rownum as rn, 'b' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; --Act - ut3.ut.expect(l_actual).to_include(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('RN'); + ut3.ut.expect(l_actual).not_to_contain(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('RN'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure not_inc_join_excl_cols_as_lst is + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'y' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; + open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + --Act + ut3.ut.expect(l_actual).not_to_include(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('RN'); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; @@ -2290,7 +2416,7 @@ Diff:% open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'y' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; --Act - ut3.ut.expect(l_actual).to_include(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('RN'); + ut3.ut.expect(l_actual).not_to_contain(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('RN'); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index 9085bd2fc..a9e8ab593 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -319,29 +319,47 @@ create or replace package test_expectations_cursor is --%test( Unordered fix for issues with duplicate no : #764 ) procedure unordered_fix_764; - --%test( Fail cursor contains data from another cursor ) - procedure cursor_contain_fail; + --%test( Fail cursor to include data from another cursor ) + procedure cursor_to_include_fail; - --%test( Cursor contains data from another cursor using second keyword) - procedure cursor_to_contain; + --%test( Cursor include data from another cursor using second keyword) + procedure cursor_to_include; --%test( Fail cursor contains data from another cursor using second keyword) procedure cursor_to_contain_fail; + --%test( Cursor include data from another cursor with joinby) + procedure cursor_to_include_joinby; + + --%test( Fail cursor include data from another cursor with joinby) + procedure cursor_to_include_joinby_fail; + --%test( Cursor contains data from another cursor with joinby) procedure cursor_contain_joinby; --%test( Fail cursor contains data from another cursor with joinby) - procedure cursor_contain_joinby_fail; + procedure cursor_contain_joinby_fail; + --%test(Cursor include data with of columns to include) + procedure to_include_incl_cols_as_list; + --%test(Cursor contains data with of columns to include) - procedure contain_incl_cols_as_list; + procedure to_contain_cont_cols_as_list; + + --%test(Cursor includes data with of columns to include and join by value) + procedure to_inc_join_incl_cols_as_lst; + + --%test(Cursor contains data with of columns to include and join by value) + procedure to_cont_join_incl_cols_as_lst; - --%test(Cursor contains data with of columns to include and join by value) - procedure contain_join_incl_cols_as_lst; + --%test(Cursor include data with of columns to exclude and join by value) + procedure include_join_excl_cols_as_lst; --%test(Cursor contains data with of columns to exclude and join by value) procedure contain_join_excl_cols_as_lst; + + --%test(Cursor include data with of columns to exclude) + procedure include_excl_cols_as_list; --%test(Cursor contains data with of columns to exclude) procedure contain_excl_cols_as_list; @@ -357,10 +375,16 @@ create or replace package test_expectations_cursor is --%test( Cursor not include data from another cursor with joinby clause) procedure cursor_not_to_include_joinby; + + --%test(Cursor not include data with of columns to include and join by value) + procedure not_inc_join_incl_cols_as_lst; --%test(Cursor not contains data with of columns to include and join by value) procedure not_cont_join_incl_cols_as_lst; + --%test(Cursor not include data with of columns to exclude and join by value) + procedure not_inc_join_excl_cols_as_lst; + --%test(Cursor not contains data with of columns to exclude and join by value) procedure not_cont_join_excl_cols_as_lst; From 5aa19ea7f1a839f0975938845277c4688ca84bce Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 21 Oct 2018 20:14:40 +0100 Subject: [PATCH 22/83] Update some of the format --- source/expectations/data_values/ut_compound_data_helper.pkb | 1 + source/expectations/data_values/ut_compound_data_value.tpb | 4 +++- source/expectations/data_values/ut_data_value_refcursor.tpb | 3 ++- source/expectations/matchers/ut_equal.tps | 4 ++-- 4 files changed, 8 insertions(+), 4 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index fc571e372..d1ab6b6a4 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -176,6 +176,7 @@ create or replace package body ut_compound_data_helper is l_results tt_row_diffs; begin l_column_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath); + /** * Since its unordered search we cannot select max rows from diffs as we miss some comparision records * We will restrict output on higher level of select diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index d12817cee..3ff986d17 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -107,6 +107,7 @@ create or replace type body ut_compound_data_value as l_actual := treat(a_other as ut_compound_data_value); dbms_lob.createtemporary(l_result,true); + --diff rows and row elements l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); @@ -114,6 +115,7 @@ create or replace type body ut_compound_data_value as execute immediate 'select count('||case when a_join_by_xpath is not null then 'distinct pk_hash' else '*' end||') from ' || l_ut_owner || '.ut_compound_data_diff_tmp where diff_id = :diff_id' into l_diff_row_count using l_diff_id; + if l_diff_row_count > 0 then l_compare_type := ut_compound_data_helper.compare_type(a_join_by_xpath,a_unordered); l_row_diffs := ut_compound_data_helper.get_rows_diff( @@ -222,7 +224,7 @@ create or replace type body ut_compound_data_value as if not a_other is of (ut_compound_data_value) then raise value_error; end if; - + l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index f380b86f8..5266a90bf 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -248,7 +248,7 @@ create or replace type body ut_data_value_refcursor as then l_result := 1; end if; - + if a_unordered then l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, a_join_by_xpath, a_unordered, a_inclusion_compare, a_is_negated); @@ -265,5 +265,6 @@ create or replace type body ut_data_value_refcursor as return self.elements_count = 0; end; + end; / diff --git a/source/expectations/matchers/ut_equal.tps b/source/expectations/matchers/ut_equal.tps index a2b984c63..0ccbd23c8 100644 --- a/source/expectations/matchers/ut_equal.tps +++ b/source/expectations/matchers/ut_equal.tps @@ -1,4 +1,4 @@ -create or replace type ut_equal force under ut_comparison_matcher( +create or replace type ut_equal under ut_comparison_matcher( /* utPLSQL - Version 3 Copyright 2016 - 2018 utPLSQL Project @@ -71,4 +71,4 @@ create or replace type ut_equal force under ut_comparison_matcher( overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2 ) not final -/ \ No newline at end of file +/ From 03ad5ecc1431a97538250005fdec42bd58fb67d4 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 27 Oct 2018 16:10:11 +0100 Subject: [PATCH 23/83] Update documentation --- docs/userguide/advanced_data_comparison.md | 97 ++++++-- docs/userguide/expectations.md | 244 +++++++++++++++++++-- 2 files changed, 309 insertions(+), 32 deletions(-) diff --git a/docs/userguide/advanced_data_comparison.md b/docs/userguide/advanced_data_comparison.md index 3eb45fe50..2b27bf54e 100644 --- a/docs/userguide/advanced_data_comparison.md +++ b/docs/userguide/advanced_data_comparison.md @@ -6,7 +6,7 @@ utPLSQL expectations incorporates advanced data comparison options when comparin - object type - nested table and varray -Advanced data-comparison options are available for the [`equal`](expectations.md#equal) matcher. +Advanced data-comparison options are available for the [`equal`](expectations.md#equal) and [`include/ contain`](expectations.md#include) matcher. ## Syntax @@ -15,6 +15,10 @@ Advanced data-comparison options are available for the [`equal`](expectations.md ut.expect( a_actual {data-type} ).not_to( equal( a_expected {data-type})[.extendend_option()[.extendend_option()[...]]]) ); ut.expect( a_actual {data-type} ).to_equal( a_expected {data-type})[.extendend_option()[.extendend_option()[...]]]); ut.expect( a_actual {data-type} ).not_to_equal( a_expected {data-type})[.extendend_option()[.extendend_option()[...]]] ); + ut.expect( a_actual {data-type} ).to_contain( a_expected {data-type})[.extendend_option()[.extendend_option()[...]]]); + ut.expect( a_actual {data-type} ).to_include( a_expected {data-type})[.extendend_option()[.extendend_option()[...]]]); + ut.expect( a_actual {data-type} ).not_to_include( a_expected {data-type})[.extendend_option()[.extendend_option()[...]]]); + ut.expect( a_actual {data-type} ).not_to_contain( a_expected {data-type})[.extendend_option()[.extendend_option()[...]]]); ``` `extended_option` can be one of: @@ -23,8 +27,8 @@ Advanced data-comparison options are available for the [`equal`](expectations.md - `exclude(a_items varchar2)` - item or comma separated list of items to exclude - `include(a_items ut_varchar2_list)` - table of items to include - `exclude(a_items ut_varchar2_list)` - table of items to exclude - - `unordered` - perform compare on unordered set of data, return only missing or actual - - `join_by(a_columns varchar2)` - columns or comma seperated list of columns to join two cursors by + - `unordered` - perform compare on unordered set of data, return only missing or actual ***not supported for `include / contain`*** + - `join_by(a_columns varchar2)` - columns or comma separated list of columns to join two cursors by - `join_by(a_columns ut_varchar2_list)` - table of columns to join two cursors by Each item in the comma separated list can be: @@ -42,9 +46,9 @@ When specifying column/attribute names, keep in mind that the names are **case s ## Excluding elements from data comparison -Consider the following example +Consider the following examples ```sql -procedure test_cursors_skip_columns is +procedure test_cur_skip_columns_eq is l_expected sys_refcursor; l_actual sys_refcursor; begin @@ -52,10 +56,19 @@ begin open l_actual for select sysdate "ADate", d.* from user_tables d; ut.expect( l_actual ).to_equal( l_expected ).exclude( 'IGNORE_ME,ADate' ); end; + +procedure test_cur_skip_columns_cn is + l_expected sys_refcursor; + l_actual sys_refcursor; +begin + open l_expected for select 'text' ignore_me, d.* from user_tables d; + open l_actual for select sysdate "ADate", d.* from user_tables d; + ut.expect( l_actual ).to_include( l_expected ).exclude( 'IGNORE_ME,ADate' ); +end; ``` Columns 'ignore_me' and "ADate" will get excluded from cursor comparison. -The cursor data is equal, when those columns are excluded. +The cursor data is equal or includes expected, when those columns are excluded. This option is useful in scenarios, when you need to exclude incomparable/unpredictable column data like CREATE_DATE of a record that is maintained by default value on a table column. @@ -63,7 +76,7 @@ This option is useful in scenarios, when you need to exclude incomparable/unpred Consider the following example ```sql -procedure include_columns_as_csv is +procedure include_col_as_csv_eq is l_actual sys_refcursor; l_expected sys_refcursor; begin @@ -71,14 +84,23 @@ begin open l_actual for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL, a.* from all_objects a where rownum < 4; ut.expect( l_actual ).to_equal( l_expected ).include( 'RN,A_Column,SOME_COL' ); end; + +procedure include_col_as_csv_cn is + l_actual sys_refcursor; + l_expected sys_refcursor; +begin + open l_expected for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL from dual a connect by level < 4; + open l_actual for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL, a.* from all_objects a where rownum < 6; + ut.expect( l_actual ).to_contain( l_expected ).include( 'RN,A_Column,SOME_COL' ); +end; ``` ## Combining include/exclude options You can chain the advanced options in an expectation and mix the `varchar2` with `ut_varchar2_list` arguments. -When doing so, the fianl list of items to include/exclude will be a concatenation of all items. +When doing so, the final list of items to include/exclude will be a concatenation of all items. ```sql -procedure include_columns_as_csv is +procedure include_col_as_csv_eq is l_actual sys_refcursor; l_expected sys_refcursor; begin @@ -89,6 +111,19 @@ begin .include( ut_varchar2_list( 'A_Column', 'SOME_COL' ) ) .exclude( 'SOME_COL' ); end; + +procedure include_col_as_csv_cn is + l_actual sys_refcursor; + l_expected sys_refcursor; +begin + open l_expected for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL from dual a connect by level < 4; + open l_actual for select rownum as rn, 'a' as "A_Column", 'Y' SOME_COL, a.* from all_objects a where rownum < 6; + ut.expect( l_actual ).to_contain( l_expected ) + .include( 'RN') + .include( ut_varchar2_list( 'A_Column', 'SOME_COL' ) ) + .exclude( 'SOME_COL' ); +end; + ``` Only the columns 'RN', "A_Column" will be compared. Column 'SOME_COL' is excluded. @@ -101,6 +136,8 @@ Unordered option allows for quick comparison of two cursors without need of orde Result of such comparison will be limited to only information about row existing or not existing in given set without actual information about exact differences. +**This option is not supported for `include / contain` matcher** + ```sql @@ -169,6 +206,33 @@ This will show you difference in row 'TEST' regardless of order. Assumption is that join by is made by column name so that what will be displayed as part of results. +Consider this example using `contain / include ` + +```sql +procedure join_by_username_cn is + l_actual sys_refcursor; + l_expected sys_refcursor; +begin + open l_actual for select username, user_id from all_users; + open l_expected for select username, user_id from all_users + union all + select 'TEST' username, -610 user_id from dual; + + ut.expect( l_actual ).to_contain( l_expected ).join_by('USERNAME'); +end; +``` + +This will show you that one value is not included in actual set: + +```sql + Actual: refcursor [ count = 43 ] was expected to include: refcursor [ count = 44 ] + Diff: + Rows: [ 1 differences ] + PK TEST - Missing -610 +``` + + + Join by options currently doesn't support nested table inside cursor comparison, however is still possible to compare a collection as a whole. Example. @@ -220,9 +284,7 @@ Diff: - - -**Please note that .join_by option will take longer to process due to need of parsing via primary keys.** +***Please note that .join_by option will take longer to process due to need of parsing via primary keys.*** ## Defining item as XPath When using XPath expression, keep in mind the following: @@ -233,7 +295,7 @@ When using XPath expression, keep in mind the following: Example of a valid XPath parameter to include columns: `RN`, `A_Column`, `SOME_COL` in data comparison. ```sql -procedure include_columns_as_xpath is +procedure include_col_as_xpath_eq is l_actual sys_refcursor; l_expected sys_refcursor; begin @@ -241,4 +303,13 @@ begin open l_actual for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL, a.* from all_objects a where rownum < 4; ut.expect( l_actual ).to_equal( l_expected ).include( '/ROW/RN|/ROW/A_Column|/ROW/SOME_COL' ); end; + +procedure include_col_as_xpath_cn is + l_actual sys_refcursor; + l_expected sys_refcursor; +begin + open l_expected for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL from dual a connect by level < 4; + open l_actual for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL, a.* from all_objects a where rownum < 6; + ut.expect( l_actual ).to_include( l_expected ).include( '/ROW/RN|/ROW/A_Column|/ROW/SOME_COL' ); +end; ``` diff --git a/docs/userguide/expectations.md b/docs/userguide/expectations.md index 4c6f3aa68..b013a6d9a 100644 --- a/docs/userguide/expectations.md +++ b/docs/userguide/expectations.md @@ -145,6 +145,7 @@ utPLSQL provides the following matchers to perform checks on the expected and ac - `be_null` - `be_true` - `equal` +- `include ` / `contain` - `have_count` - `match` @@ -432,6 +433,210 @@ end; The `a_nulls_are_equal` parameter controls the behavior of a `null = null` comparison. To change the behavior of `NULL = NULL` comparison pass the `a_nulls_are_equal => false` to the `equal` matcher. +## include / contain + +This matcher supports only cursor comparison. It check if the give set contain all values from given subset. + +Test using this matcher behaves similar to `equal` in respect that it succeeds only when the compared data-types are exactly the same. + +The matcher supports all advanced comparison options as `equal` e.g. include , exclude, join_by. + +The matcher will be successful only when all of the values in expected results are part of actual set. + +Similar negated `not_to_include`/ `not_to_contain` will be successful only when none of the values from expected set are part of actual e.g. + +*Example 1.* + +Set 1 is defined as [ A , B , C ] + +*Set 2 is defined as [A , D , E ]* + +*Result : This will fail both of options to`to_include` and `not_to_include`* + + + +*Example 2.* + +Set 1 is defined as [ A , B , C , D ] + +*Set 2 is defined as [A , B , D ]* + +*Result : This will be success on option `to_include` and fail `not_to_include`* + + + +*Example 3* + +Set 1 is defined as [ A , B , C ] + +*Set 2 is defined as [D, E , F ]* + +*Result : This will be success on options `not_to_include` and fail `to_include`* + + + +Example usage + +```sql +create or replace package example_include is + --%suite(Include test) + + --%test( Cursor include data from another cursor) + procedure cursor_to_include; + + --%test( Cursor include data from another cursor) + procedure cursor_not_to_include; + + --%test( Cursor fail include) + procedure cursor_fail_include; + + --%test( Cursor fail not include) + procedure cursor_fail_not_include; +end; +/ + +create or replace package body example_include is + + procedure cursor_to_include is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for + select 'a' as name from dual + union all + select 'b' as name from dual + union all + select 'c' as name from dual + union all + select 'd' as name from dual; + + open l_expected for + select 'a' as name from dual + union all + select 'b' as name from dual + union all + select 'c' as name from dual; + + --Act + ut3.ut.expect(l_actual).to_include(l_expected); + end; + + procedure cursor_not_to_include is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for + select 'a' as name from dual + union all + select 'b' as name from dual + union all + select 'c' as name from dual; + + open l_expected for + select 'd' as name from dual + union all + select 'e' as name from dual + union all + select 'f' as name from dual; + + --Act + ut3.ut.expect(l_actual).not_to_include(l_expected); + end; + + procedure cursor_fail_include is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for + select 'a' as name from dual + union all + select 'b' as name from dual + union all + select 'c' as name from dual; + + open l_expected for + select 'a' as name from dual + union all + select 'd' as name from dual + union all + select 'e' as name from dual; + + --Act + ut3.ut.expect(l_actual).to_include(l_expected); + end; + + procedure cursor_fail_not_include is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for + select 'a' as name from dual + union all + select 'b' as name from dual + union all + select 'c' as name from dual; + + open l_expected for + select 'a' as name from dual + union all + select 'd' as name from dual + union all + select 'e' as name from dual; + + --Act + ut3.ut.expect(l_actual).not_to_include(l_expected); + end; +end; +/ +``` + + + +Above execution will provide results as follow: + +```sql +Include test + Cursor include data from another cursor [.045 sec] + Cursor include data from another cursor [.039 sec] + Cursor fail include [.046 sec] (FAILED - 1) + Cursor fail not include [.043 sec] (FAILED - 2) + +Failures: + + 1) cursor_fail_include + Actual: refcursor [ count = 3 ] was expected to include: refcursor [ count = 3 ] + Diff: + Rows: [ 2 differences ] + Missing: d + Missing: e + at "UT3.EXAMPLE_INCLUDE.CURSOR_FAIL_INCLUDE", line 71 ut3.ut.expect(l_actual).to_include(l_expected); + + + 2) cursor_fail_not_include + Actual: (refcursor [ count = 3 ]) + Data-types: + CHAR + + Data: + a + b + c + was expected not to include:(refcursor [ count = 3 ]) + Data-types: + CHAR + + Data: + a + d + e + at "UT3.EXAMPLE_INCLUDE.CURSOR_FAIL_NOT_INCLUDE", line 94 ut3.ut.expect(l_actual).not_to_include(l_expected); +``` + + ## Comparing cursors, object types, nested tables and varrays @@ -450,7 +655,7 @@ utPLSQL is capable of comparing compound data-types including: - It is possible to compare PL/SQL records, collections, varrays and associative arrays. To compare this types of data, use cursor comparison feature of utPLSQL and TABLE operator in SQL query - On Oracle 11g Release 2 - pipelined table functions are needed (see section [Implicit (Shadow) Types in this artcile](https://oracle-base.com/articles/misc/pipelined-table-functions)) - On Oracle 12c and above - use [TABLE function on nested tables/varrays/associative arrays of PL/SQL records](https://oracle-base.com/articles/12c/using-the-table-operator-with-locally-defined-types-in-plsql-12cr1) - + utPLSQL offers advanced data-comparison options, for comparing compound data-types. The options allow you to: - define columns/attributes to exclude from comparison @@ -784,23 +989,24 @@ Since NULL is neither *true* nor *false*, both expectations will report failure. The matrix below illustrates the data types supported by different matchers. -| Matcher |blob |boolean|clob |date |number|timestamp|timestamp
with
timezone|timestamp
with
local
timezone|varchar2|interval
year
to
month|interval
day
to
second|cursor|nested
table
/ varray|object| -|:----------------------|:---:|:-----:|:---:|:---:|:----:|:-------:|:---------------------------:|:------------------------------------:|:------:|:-----------------------------:|:-----------------------------:|:----:|:-------------------------:|:----:| -|**be_not_null** | X | X | X | X | X | X | X | X | X | X | X | X | X | X | -|**be_null** | X | X | X | X | X | X | X | X | X | X | X | X | X | X | -|**be_false** | | X | | | | | | | | | | | | | -|**be_true** | | X | | | | | | | | | | | | | -|**be_greater_than** | | | | X | X | X | X | X | | X | X | | | | -|**be_greater_or_equal**| | | | X | X | X | X | X | | X | X | | | | -|**be_less_or_equal** | | | | X | X | X | X | X | | X | X | | | | -|**be_less_than** | | | | X | X | X | X | X | | X | X | | | | -|**be_between** | | | | X | X | X | X | X | X | X | X | | | | -|**equal** | X | X | X | X | X | X | X | X | X | X | X | X | X | X | -|**match** | | | X | | | | | | X | | | | | | -|**be_like** | | | X | | | | | | X | | | | | | -|**be_empty** | X | | X | | | | | | | | | X | X | | -|**have_count** | | | | | | | | | | | | X | X | | - - +| Matcher | blob | boolean | clob | date | number | timestamp | timestamp
with
timezone | timestamp
with
local
timezone | varchar2 | interval
year
to
month | interval
day
to
second | cursor | nested
table
/ varray | object | +| :---------------------- | :--: | :-----: | :--: | :--: | :----: | :-------: | :---------------------------: | :------------------------------------: | :------: | :-----------------------------: | :-----------------------------: | :----: | :-------------------------: | :----: | +| **be_not_null** | X | X | X | X | X | X | X | X | X | X | X | X | X | X | +| **be_null** | X | X | X | X | X | X | X | X | X | X | X | X | X | X | +| **be_false** | | X | | | | | | | | | | | | | +| **be_true** | | X | | | | | | | | | | | | | +| **be_greater_than** | | | | X | X | X | X | X | | X | X | | | | +| **be_greater_or_equal** | | | | X | X | X | X | X | | X | X | | | | +| **be_less_or_equal** | | | | X | X | X | X | X | | X | X | | | | +| **be_less_than** | | | | X | X | X | X | X | | X | X | | | | +| **be_between** | | | | X | X | X | X | X | X | X | X | | | | +| **equal** | X | X | X | X | X | X | X | X | X | X | X | X | X | X | +| **include / contain** | | | | | | | | | | | | X | X | X | +| **match** | | | X | | | | | | X | | | | | | +| **be_like** | | | X | | | | | | X | | | | | | +| **be_empty** | X | | X | | | | | | | | | X | X | | +| **have_count** | | | | | | | | | | | | X | X | | + +​ From 42563e90b1f0f44cd84c8c44f735332c8de45f8e Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 1 Nov 2018 20:19:12 +0000 Subject: [PATCH 24/83] Update documentation and added additional test. --- docs/userguide/expectations.md | 35 +++++++++++++++- .../expectations/test_expectations_cursor.pkb | 41 +++++++++++++++++++ .../expectations/test_expectations_cursor.pks | 6 +++ 3 files changed, 81 insertions(+), 1 deletion(-) diff --git a/docs/userguide/expectations.md b/docs/userguide/expectations.md index b013a6d9a..ac74510c1 100644 --- a/docs/userguide/expectations.md +++ b/docs/userguide/expectations.md @@ -443,9 +443,42 @@ The matcher supports all advanced comparison options as `equal` e.g. include , e The matcher will be successful only when all of the values in expected results are part of actual set. +In situation where the duplicate is present in expected set we would also expect matching number of occurrences in actual set for matcher to be success. + +*Example 1* + +```sql + PROCEDURE ut_refcursors IS + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select rownum as rn from dual a connect by level < 10; + open l_expected for select rownum as rn from dual a connect by level < 4 + union all select rownum as rn from dual a connect by level < 4; + + --Act + ut.expect(l_actual).to_include(l_expected); + END; +``` + +Will result in failure message + +```sql + 1) ut_refcursors + Actual: refcursor [ count = 9 ] was expected to include: refcursor [ count = 6 ] + Diff: + Rows: [ 3 differences ] + Missing: 3 + Missing: 2 + Missing: 1 +``` + + + Similar negated `not_to_include`/ `not_to_contain` will be successful only when none of the values from expected set are part of actual e.g. -*Example 1.* +*Example 2.* Set 1 is defined as [ A , B , C ] diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 3778bd93f..04bbbe5d9 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2420,6 +2420,47 @@ Diff:% --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + + procedure to_include_duplicates is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select rownum as rn from dual a connect by level < 10 + union all + select rownum as rn from dual a connect by level < 4; + open l_expected for select rownum as rn from dual a connect by level < 4; + + --Act + ut3.ut.expect(l_actual).to_include(l_expected); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure to_include_duplicates_fail is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); + begin + --Arrange + open l_actual for select rownum as rn from dual a connect by level < 10; + open l_expected for select rownum as rn from dual a connect by level < 4 + union all select rownum as rn from dual a connect by level < 4; + + --Act + ut3.ut.expect(l_actual).to_include(l_expected); + --Assert + l_expected_message := q'[%Actual: refcursor [ count = 9 ] was expected to include: refcursor [ count = 6 ] +%Diff: +%Rows: [ 3 differences ] +%Missing: % +%Missing: % +%Missing: %]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + end; end; / diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index a9e8ab593..ca9977f41 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -387,6 +387,12 @@ create or replace package test_expectations_cursor is --%test(Cursor not contains data with of columns to exclude and join by value) procedure not_cont_join_excl_cols_as_lst; + + --%test(Cursor to include duplicates) + procedure to_include_duplicates; + + --%test(Cursor to include duplicates fail) + procedure to_include_duplicates_fail; end; / From 2a133a1e91cb25af571ec145b4cd8266e52ab36f Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 27 Oct 2018 15:13:59 +0100 Subject: [PATCH 25/83] Fix to issue #770 when the merge statement is run via current user which can result in error due to missing privs to internal function --- .../data_values/ut_compound_data_helper.pkb | 53 +++++++++++++++++++ .../data_values/ut_compound_data_helper.pks | 3 ++ .../data_values/ut_compound_data_value.tpb | 47 ++-------------- 3 files changed, 59 insertions(+), 44 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index d1ab6b6a4..9860d82bf 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -541,6 +541,59 @@ create or replace package body ut_compound_data_helper is return l_no_missing_keys; end; + procedure update_row_and_pk_hash(a_self_data_id in raw, a_other_data_id in raw, a_exclude_xpath varchar2, + a_include_xpath varchar2, a_join_by_xpath varchar2) is + l_ut_owner varchar2(250) := ut_utils.ut_owner; + l_column_filter varchar2(32767); + l_pk_hash_sql varchar2(32767); + + function get_column_pk_hash(a_join_by_xpath varchar2) return varchar2 is + l_column varchar2(32767); + begin + /* due to possibility of key being to columns we cannot use xmlextractvalue + usage of xmlagg is possible however it greatly complicates code and performance is impacted. + xpath to be looked at or regex + */ + if a_join_by_xpath is not null then + l_column := l_ut_owner ||'.ut_compound_data_helper.get_hash(extract(ucd.item_data,:join_by_xpath).GetClobVal()) pk_hash'; + else + l_column := ':join_by_xpath pk_hash'; + end if; + return l_column; + end; + + begin + l_column_filter := ut_compound_data_helper.get_columns_filter(a_exclude_xpath, a_include_xpath); + l_pk_hash_sql := get_column_pk_hash(a_join_by_xpath); + + execute immediate 'merge into ' || l_ut_owner || '.ut_compound_data_tmp tgt + using ( + select ucd_out.item_hash, + ucd_out.pk_hash, + ucd_out.item_no, + ucd_out.data_id, + row_number() over (partition by ucd_out.pk_hash,ucd_out.item_hash,ucd_out.data_id order by 1,2) duplicate_no + from + ( + select '||l_ut_owner ||'.ut_compound_data_helper.get_hash(ucd.item_data.getclobval()) item_hash, + pk_hash, ucd.item_no, ucd.data_id + from + ( + select '||l_column_filter||','||l_pk_hash_sql||', item_no, data_id + from ' || l_ut_owner || q'[.ut_compound_data_tmp ucd + where data_id = :self_guid or data_id = :other_guid + ) ucd + )ucd_out + ) src + on (tgt.item_no = src.item_no and tgt.data_id = src.data_id) + when matched then update + set tgt.item_hash = src.item_hash, + tgt.pk_hash = src.pk_hash, + tgt.duplicate_no = src.duplicate_no]' + using a_exclude_xpath, a_include_xpath,a_join_by_xpath,a_self_data_id, a_other_data_id; + + end; + function get_unordered(a_owner in varchar2) return varchar2 is l_sql varchar2(32767); begin diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 32512e391..e992fd48b 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -83,5 +83,8 @@ create or replace package ut_compound_data_helper authid definer is function get_refcursor_matcher_sql(a_owner in varchar2,a_inclusion_matcher boolean := false, a_negated_match boolean := false) return varchar2; + procedure update_row_and_pk_hash(a_self_data_id in raw, a_other_data_id in raw, a_exclude_xpath varchar2, + a_include_xpath varchar2, a_join_by_xpath varchar2); + end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 3ff986d17..49fe272eb 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -198,28 +198,12 @@ create or replace type body ut_compound_data_value as a_unordered boolean , a_inclusion_compare boolean := false, a_is_negated boolean := false ) return integer is l_other ut_compound_data_value; l_ut_owner varchar2(250) := ut_utils.ut_owner; - l_column_filter varchar2(32767); l_diff_id ut_compound_data_helper.t_hash; l_result integer; l_row_diffs ut_compound_data_helper.tt_row_diffs; c_max_rows constant integer := 20; l_sql varchar2(32767); - function get_column_pk_hash(a_join_by_xpath varchar2) return varchar2 is - l_column varchar2(32767); - begin - /* due to possibility of key being to columns we cannot use xmlextractvalue - usage of xmlagg is possible however it greatly complicates code and performance is impacted. - xpath to be looked at or regex - */ - if a_join_by_xpath is not null then - l_column := l_ut_owner ||'.ut_compound_data_helper.get_hash(extract(ucd.item_data,:join_by_xpath).GetClobVal()) pk_hash'; - else - l_column := ':join_by_xpath pk_hash'; - end if; - return l_column; - end; - begin if not a_other is of (ut_compound_data_value) then raise value_error; @@ -228,37 +212,12 @@ create or replace type body ut_compound_data_value as l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - l_column_filter := ut_compound_data_helper.get_columns_filter(a_exclude_xpath, a_include_xpath); - + /** * Due to incompatibility issues in XML between 11 and 12.2 and 12.1 versions we will prepopulate pk_hash upfront to * avoid optimizer incorrectly rewrite and causing NULL error or ORA-600 - **/ - execute immediate 'merge into ' || l_ut_owner || '.ut_compound_data_tmp tgt - using ( - select ucd_out.item_hash, - ucd_out.pk_hash, - ucd_out.item_no, - ucd_out.data_id, - row_number() over (partition by ucd_out.pk_hash,ucd_out.item_hash,ucd_out.data_id order by 1,2) duplicate_no - from - ( - select '||l_ut_owner ||'.ut_compound_data_helper.get_hash(ucd.item_data.getclobval()) item_hash, - pk_hash, ucd.item_no, ucd.data_id - from - ( - select '||l_column_filter||','||get_column_pk_hash(a_join_by_xpath)||', item_no, data_id - from ' || l_ut_owner || q'[.ut_compound_data_tmp ucd - where data_id = :self_guid or data_id = :other_guid - ) ucd - )ucd_out - ) src - on (tgt.item_no = src.item_no and tgt.data_id = src.data_id) - when matched then update - set tgt.item_hash = src.item_hash, - tgt.pk_hash = src.pk_hash, - tgt.duplicate_no = src.duplicate_no]' - using a_exclude_xpath, a_include_xpath,a_join_by_xpath,self.data_id, l_other.data_id; + **/ + ut_compound_data_helper.update_row_and_pk_hash(self.data_id, l_other.data_id, a_exclude_xpath,a_include_xpath,a_join_by_xpath); /*!* * Comparision is based on type of search, for inclusion based search we will look for left join only. From 68d43d6681493f717de6c7b1946aad2fa1781e03 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 28 Oct 2018 07:48:16 +0000 Subject: [PATCH 26/83] Added test for min user test --- test/install__min_usr_tests.sql | 39 ++++++++++++++++++++++ test/install_and_run_tests.sh | 30 ++++++++++++++++- test/min_grant_user/min_grant_user_exp.pkb | 19 +++++++++++ test/min_grant_user/min_grant_user_exp.pks | 9 +++++ 4 files changed, 96 insertions(+), 1 deletion(-) create mode 100644 test/install__min_usr_tests.sql create mode 100644 test/min_grant_user/min_grant_user_exp.pkb create mode 100644 test/min_grant_user/min_grant_user_exp.pks diff --git a/test/install__min_usr_tests.sql b/test/install__min_usr_tests.sql new file mode 100644 index 000000000..fa788f8f9 --- /dev/null +++ b/test/install__min_usr_tests.sql @@ -0,0 +1,39 @@ +set define off +whenever sqlerror exit failure rollback +whenever oserror exit failure rollback + +alter session set plsql_optimize_level=0; + +--Install tests +@@min_grant_user/min_grant_user_exp.pks +@@min_grant_user/min_grant_user_exp.pkb + +set linesize 200 +set define on +set verify off +column text format a100 +column error_count noprint new_value error_count + +prompt Validating installation + +set heading on +select type, name, sequence, line, position, text, count(1) over() error_count + from all_errors + where owner = USER + and name not like 'BIN$%' --not recycled + and name != 'UT_WITH_INVALID_BODY' + -- errors only. ignore warnings + and attribute = 'ERROR' + order by name, type, sequence +/ + +begin + if to_number('&&error_count') > 0 then + raise_application_error(-20000, 'Not all sources were successfully installed.'); + else + dbms_output.put_line('Installation completed successfully'); + end if; +end; +/ + +exit; diff --git a/test/install_and_run_tests.sh b/test/install_and_run_tests.sh index a1e5e0849..04d70fb39 100644 --- a/test/install_and_run_tests.sh +++ b/test/install_and_run_tests.sh @@ -1,10 +1,35 @@ #!/bin/bash set -ev +check_result() +{ + RC1=$1 + RC2=$2 + + if [ "$RC1" != "0" ] || [ "$RC2" != "0" ]; then + return 1 + fi + return 0 +} #goto git root directory git rev-parse && cd "$(git rev-parse --show-cdup)" +cd test + +time "$SQLCLI" ${UT3_USER}/${UT3_USER_PASSWORD}@//${CONNECTION_STR} @install__min_usr_tests.sql + +cd .. + +time utPLSQL-cli/bin/utplsql run ${UT3_USER}/${UT3_USER_PASSWORD}@${CONNECTION_STR} \ +-source_path=source -owner=ut3 \ +-test_path=test -c \ +-f=ut_documentation_reporter -o=min_test_results.log -s \ +-scc + +status_line_regex="^[0-9]+ tests, ([0-9]+) failed, ([0-9]+) errored.*" + +RC1=$(cat min_test_results.log | grep -E "${status_line_regex}" | sed -re "s/${status_line_regex}/\1\2/") cd test @@ -29,6 +54,9 @@ status_line_regex="^[0-9]+ tests, ([0-9]+) failed, ([0-9]+) errored.*" #cat coverage.xml #cat test_results.xml -RC=$(cat test_results.log | grep -E "${status_line_regex}" | sed -re "s/${status_line_regex}/\1\2/") +RC2=$(cat test_results.log | grep -E "${status_line_regex}" | sed -re "s/${status_line_regex}/\1\2/") + +check_result $RC1 $RC2 +RC=$? exit $RC diff --git a/test/min_grant_user/min_grant_user_exp.pkb b/test/min_grant_user/min_grant_user_exp.pkb new file mode 100644 index 000000000..1a8089c0b --- /dev/null +++ b/test/min_grant_user/min_grant_user_exp.pkb @@ -0,0 +1,19 @@ +create or replace package body min_grant_user_exp is + + procedure test_join_by_cursor is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select owner, object_name,object_type from all_objects where owner = user + order by 1,2,3 asc; + open l_expected for select owner, object_name,object_type from all_objects where owner = user + order by 1,2,3 desc; + + --Act + ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OWNER'); + + end; + +end; +/ diff --git a/test/min_grant_user/min_grant_user_exp.pks b/test/min_grant_user/min_grant_user_exp.pks new file mode 100644 index 000000000..467d62ce0 --- /dev/null +++ b/test/min_grant_user/min_grant_user_exp.pks @@ -0,0 +1,9 @@ +create or replace package min_grant_user_exp is + + --%suite(minimum grant user tests) + + --%test(execute join by test) + procedure test_join_by_cursor; + +end; +/ From afe9e2cd9735c1a235ae62acb241575efbe72f74 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 28 Oct 2018 07:57:51 +0000 Subject: [PATCH 27/83] Update sqlcl download --- .travis/download.sh | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/.travis/download.sh b/.travis/download.sh index fdbcdef7c..44c3fa1cc 100644 --- a/.travis/download.sh +++ b/.travis/download.sh @@ -61,8 +61,8 @@ fi if [ "$PRODUCT" == "sqlcl" ]; then agreementUrl="http://www.oracle.com/technetwork/developer-tools/sqlcl/downloads/index.html" - downloadUrl="https://download.oracle.com/otn/java/sqldeveloper/sqlcl-18.3.0.259.2029.zip" - outputFile=sqlcl-18.3.0.259.2029.zip + downloadUrl="http://download.oracle.com/otn/java/sqldeveloper/sqlcl-18.2.0.zip" + outputFile=sqlcl-18.2.0.zip downloadFile $agreementUrl $downloadUrl $outputFile exit 0 fi From 12edb2a13f93dfc669dbd98c228adf6a25855683 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 1 Nov 2018 18:46:01 +0000 Subject: [PATCH 28/83] Squashed commit of the following: MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit commit 899ddcffd57b5bb66448ea8306933dafae543cc2 Author: Travis CI Date: Thu Nov 1 01:18:58 2018 +0000 Updated project version after build [skip ci] commit df9dac7b2f4b5323db7a54865bc8f0be42ca34a8 Merge: 013cba3b 2a6c82c5 Author: Jacek Gębal Date: Thu Nov 1 01:05:42 2018 +0000 Merge pull request #772 from utPLSQL/bugfix/fix_travis_sqlcl_download_vini Fix sqlcl download commit 2a6c82c513dfe08681d401873762af8d40582976 Author: Jacek Gębal Date: Sun Oct 28 08:01:14 2018 +0000 Fix sqlcl download --- .travis/download.sh | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/.travis/download.sh b/.travis/download.sh index 44c3fa1cc..fdbcdef7c 100644 --- a/.travis/download.sh +++ b/.travis/download.sh @@ -61,8 +61,8 @@ fi if [ "$PRODUCT" == "sqlcl" ]; then agreementUrl="http://www.oracle.com/technetwork/developer-tools/sqlcl/downloads/index.html" - downloadUrl="http://download.oracle.com/otn/java/sqldeveloper/sqlcl-18.2.0.zip" - outputFile=sqlcl-18.2.0.zip + downloadUrl="https://download.oracle.com/otn/java/sqldeveloper/sqlcl-18.3.0.259.2029.zip" + outputFile=sqlcl-18.3.0.259.2029.zip downloadFile $agreementUrl $downloadUrl $outputFile exit 0 fi From 9dbb4e59e009d0768e81bdf875c20b77206fef06 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 1 Nov 2018 19:10:40 +0000 Subject: [PATCH 29/83] Update run test shell. --- test/install_and_run_tests.sh | 23 +++++++---------------- 1 file changed, 7 insertions(+), 16 deletions(-) diff --git a/test/install_and_run_tests.sh b/test/install_and_run_tests.sh index 04d70fb39..79dfda65e 100644 --- a/test/install_and_run_tests.sh +++ b/test/install_and_run_tests.sh @@ -1,17 +1,6 @@ #!/bin/bash set -ev -check_result() -{ - RC1=$1 - RC2=$2 - - if [ "$RC1" != "0" ] || [ "$RC2" != "0" ]; then - return 1 - fi - return 0 -} - #goto git root directory git rev-parse && cd "$(git rev-parse --show-cdup)" @@ -29,7 +18,11 @@ time utPLSQL-cli/bin/utplsql run ${UT3_USER}/${UT3_USER_PASSWORD}@${CONNECTION_S status_line_regex="^[0-9]+ tests, ([0-9]+) failed, ([0-9]+) errored.*" -RC1=$(cat min_test_results.log | grep -E "${status_line_regex}" | sed -re "s/${status_line_regex}/\1\2/") +RC=$(cat min_test_results.log | grep -E "${status_line_regex}" | sed -re "s/${status_line_regex}/\1\2/") + +if [ "$RC" == "1" ] then + exit 1 +fi cd test @@ -54,9 +47,7 @@ status_line_regex="^[0-9]+ tests, ([0-9]+) failed, ([0-9]+) errored.*" #cat coverage.xml #cat test_results.xml -RC2=$(cat test_results.log | grep -E "${status_line_regex}" | sed -re "s/${status_line_regex}/\1\2/") - -check_result $RC1 $RC2 -RC=$? +RC=$(cat test_results.log | grep -E "${status_line_regex}" | sed -re "s/${status_line_regex}/\1\2/") exit $RC + From 8752509617ecdc015f1afa3fe9e5039b30e3a599 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 1 Nov 2018 19:18:25 +0000 Subject: [PATCH 30/83] Update shell --- test/install_and_run_tests.sh | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/test/install_and_run_tests.sh b/test/install_and_run_tests.sh index 79dfda65e..b8aba77e2 100644 --- a/test/install_and_run_tests.sh +++ b/test/install_and_run_tests.sh @@ -20,7 +20,7 @@ status_line_regex="^[0-9]+ tests, ([0-9]+) failed, ([0-9]+) errored.*" RC=$(cat min_test_results.log | grep -E "${status_line_regex}" | sed -re "s/${status_line_regex}/\1\2/") -if [ "$RC" == "1" ] then +if [ "$RC" == "1" ]; then exit 1 fi From 4138d259d5beac0a9419083512169079f63182c0 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 1 Nov 2018 20:43:10 +0000 Subject: [PATCH 31/83] Added extra test for duplicate. Added one test in min grant user to prove it works. --- test/min_grant_user/min_grant_user_exp.pkb | 16 +++++++++++++++- test/min_grant_user/min_grant_user_exp.pks | 3 +++ 2 files changed, 18 insertions(+), 1 deletion(-) diff --git a/test/min_grant_user/min_grant_user_exp.pkb b/test/min_grant_user/min_grant_user_exp.pkb index 1a8089c0b..de79219e3 100644 --- a/test/min_grant_user/min_grant_user_exp.pkb +++ b/test/min_grant_user/min_grant_user_exp.pkb @@ -14,6 +14,20 @@ create or replace package body min_grant_user_exp is ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OWNER'); end; - + + procedure test_include_cursor is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select rownum as rn from dual a connect by level < 10 + union all + select rownum as rn from dual a connect by level < 4; + open l_expected for select rownum as rn from dual a connect by level < 4; + + --Act + ut3.ut.expect(l_actual).to_include(l_expected); + end; + end; / diff --git a/test/min_grant_user/min_grant_user_exp.pks b/test/min_grant_user/min_grant_user_exp.pks index 467d62ce0..f7636d550 100644 --- a/test/min_grant_user/min_grant_user_exp.pks +++ b/test/min_grant_user/min_grant_user_exp.pks @@ -5,5 +5,8 @@ create or replace package min_grant_user_exp is --%test(execute join by test) procedure test_join_by_cursor; + --%test(execute contain test) + procedure test_include_cursor; + end; / From 8388276e6a937c52ce64889559d89e564d09bd9d Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 3 Nov 2018 21:06:58 +0000 Subject: [PATCH 32/83] First stab --- .../data_values/ut_compound_data_diff_tmp.sql | 12 +- .../data_values/ut_compound_data_helper.pkb | 174 +++++++++++++++++- .../data_values/ut_compound_data_helper.pks | 14 +- .../data_values/ut_compound_data_value.tpb | 95 +++++++++- .../data_values/ut_compound_data_value.tps | 3 +- .../ut_curr_usr_compound_helper.pkb | 54 +++++- .../ut_curr_usr_compound_helper.pks | 3 +- .../data_values/ut_data_value_refcursor.tpb | 60 ++++-- .../data_values/ut_data_value_refcursor.tps | 6 + test/install_and_run_tests.sh | 1 + 10 files changed, 373 insertions(+), 49 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_diff_tmp.sql b/source/expectations/data_values/ut_compound_data_diff_tmp.sql index a7959d4aa..c285d78fd 100644 --- a/source/expectations/data_values/ut_compound_data_diff_tmp.sql +++ b/source/expectations/data_values/ut_compound_data_diff_tmp.sql @@ -12,10 +12,14 @@ create global temporary table ut_compound_data_diff_tmp( See the License for the specific language governing permissions and limitations under the License. */ - diff_id raw(128), - item_no integer, - pk_hash raw(128), - item_hash raw(128), + diff_id raw(128), + act_data_id raw(32), + exp_data_id raw(32), + act_item_data xmltype, + exp_item_data xmltype, + item_no integer, + pk_hash raw(128), + item_hash raw(128), duplicate_no integer, constraint ut_compound_data_diff_tmp_uk1 unique (diff_id,duplicate_no,item_no,item_hash, pk_hash), constraint ut_compound_data_diff_tmp_chk check( diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 9860d82bf..eaa24d1f6 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -166,6 +166,54 @@ create or replace package body ut_compound_data_helper is select replace((extract(a_item_data,a_join_by_xpath).getclobval()),chr(10)) into l_pk_value from dual; return l_pk_value; end; + + function get_rows_diff_by_sql( + a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, + a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_join_by_xpath varchar2 + ) return tt_row_diffs is + l_column_filter varchar2(32767); + l_results tt_row_diffs; + begin + l_column_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath); + + execute immediate q'[with diff_info as + ( select act_data_id, exp_data_id, + act_item_data,exp_item_data, :join_by join_by, item_no + from ut_compound_data_diff_tmp + where diff_id = :diff_id ), + exp as ( + select exp_item_data, exp_data_id, item_no rn,rownum col_no, + nvl2(exp_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,exp_item_data),null) pk_value, + s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val + from diff_info i, + table( xmlsequence( extract(i.exp_item_data,'/*/*') ) ) s + where i.exp_data_id = :self_guid), + act as ( + select act_item_data, act_data_id, item_no rn, rownum col_no, + nvl2(act_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,act_item_data),null) pk_value, + s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val + from diff_info i, + table( xmlsequence( extract(i.act_item_data,'/*/*') ) ) s + where i.act_data_id = :other_guid) + select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value + from ( + select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item + from exp join act + on exp.rn = act.rn and exp.col_name = act.col_name + where dbms_lob.compare(exp.col_val, act.col_val) != 0) + unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') ) + union all + select item_no as rn, case when exp_data_id is null then 'Extra' else 'Missing' end as diff_type, + xmlserialize(content nvl(exp_item_data, act_item_data) no indent) diffed_row, + nvl2(i.join_by,ut3.ut_compound_data_helper.get_pk_value(i.join_by,coalesce(exp_item_data,act_item_data)),null) pk_value + from diff_info i + where act_data_id is null or exp_data_id is null]' + bulk collect into l_results + using a_join_by_xpath, a_diff_id, a_expected_dataset_guid,a_actual_dataset_guid; + + return l_results; + end; function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, @@ -438,9 +486,11 @@ create or replace package body ut_compound_data_helper is end; - function compare_type(a_join_by_xpath in varchar2,a_unordered boolean) return varchar2 is + function compare_type(a_join_by_xpath in varchar2,a_unordered boolean, a_is_sql_diffable integer := 0) return varchar2 is begin case + when a_is_sql_diffable = 1 then + return gc_compare_sql; when a_join_by_xpath is not null then return gc_compare_join_by; when a_unordered then @@ -453,23 +503,26 @@ create or replace package body ut_compound_data_helper is function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unorderdered boolean + a_join_by_xpath varchar2,a_unorderdered boolean, a_is_sql_diffable integer ) return tt_row_diffs is - l_results tt_row_diffs; - l_compare_type varchar2(10):= compare_type(a_join_by_xpath,a_unorderdered); + l_result tt_row_diffs := tt_row_diffs(); + l_compare_type varchar2(10):= compare_type(a_join_by_xpath,a_unorderdered, a_is_sql_diffable); begin case + when l_compare_type = gc_compare_sql then + l_result := get_rows_diff_by_sql(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, + a_max_rows, a_exclude_xpath, a_include_xpath ,a_join_by_xpath); when l_compare_type = gc_compare_join_by then - return get_rows_diff(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, + l_result := get_rows_diff(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, a_max_rows, a_exclude_xpath, a_include_xpath ,a_join_by_xpath); when l_compare_type = gc_compare_unordered then - return get_rows_diff_unordered(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, + l_result := get_rows_diff_unordered(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, a_max_rows, a_exclude_xpath, a_include_xpath); else - return get_rows_diff(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, + l_result := get_rows_diff(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, a_max_rows, a_exclude_xpath, a_include_xpath); end case; - + return l_result; end; function get_hash(a_data raw, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash is @@ -565,7 +618,8 @@ create or replace package body ut_compound_data_helper is begin l_column_filter := ut_compound_data_helper.get_columns_filter(a_exclude_xpath, a_include_xpath); l_pk_hash_sql := get_column_pk_hash(a_join_by_xpath); - + + --Use a item hash as pk hash for unordered execute immediate 'merge into ' || l_ut_owner || '.ut_compound_data_tmp tgt using ( select ucd_out.item_hash, @@ -690,6 +744,7 @@ create or replace package body ut_compound_data_helper is return l_sql; end; + -- TODO:Rebuild as the unordered can be done using join_by compare function get_refcursor_matcher_sql(a_owner in varchar2,a_inclusion_matcher boolean := false, a_negated_match boolean := false) return varchar2 is l_sql varchar2(32767); begin @@ -704,6 +759,105 @@ create or replace package body ut_compound_data_helper is return l_sql; end; - + + function generate_xmltab_stmt (a_column_info xmltype) return varchar2 is + l_sql_stmt varchar2(32767); + begin + for i in (select /*+ CARDINALITY(xt 100) */ + xt.name + from (select a_column_info item_data from dual) x, + xmltable( + '/ROW/*' + passing x.item_data + columns + name varchar2(4000) PATH '@xml_valid_name' + ) xt) + loop + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ',' end ||i.name||q'[ varchar2(4000) PATH ']'||i.name||q'[']'; + end loop; + return l_sql_stmt; + end; + + function generate_equal_sql (a_column_info xmltype) return varchar2 is + l_sql_stmt varchar2(32767); + begin + for i in (select /*+ CARDINALITY(xt 100) */ + xt.name + from (select a_column_info item_data from dual) x, + xmltable( + '/ROW/*' + passing x.item_data + columns + name varchar2(4000) PATH '@xml_valid_name' + ) xt) + loop + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.name||q'[ = ]'||' e.'||i.name; + end loop; + return l_sql_stmt; + end; + + function generate_not_equal_sql (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2 is + l_sql_stmt varchar2(32767); + l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); + begin + l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); + + for i in ( + with xpaths_tab as (select column_value xpath from table(l_pk_xpath_tabs)), + pk_names as (select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$') name + from xpaths_tab) + select /*+ CARDINALITY(xt 100) */ + xt.name + from (select a_column_info item_data from dual) x, + xmltable( + '/ROW/*' + passing x.item_data + columns + name varchar2(4000) PATH '@xml_valid_name' + ) xt + where not exists (select 1 from pk_names p where lower(p.name) = lower(xt.name)) + ) + loop + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' or ' end ||' a.'||i.name||q'[ <> ]'||' e.'||i.name; + end loop; + return l_sql_stmt; + end; + + function generate_join_by_on_stmt (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2 is + l_sql_stmt varchar2(32767); + l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); + + begin + l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); + + for i in (with xpaths_tab as (select column_value xpath from table(l_pk_xpath_tabs)) + select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$') name + from xpaths_tab) + loop + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.name||q'[ = ]'||' e.'||i.name; + end loop; + return l_sql_stmt; + end; + + function generate_join_null_sql (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2 is + l_sql_stmt varchar2(32767); + l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); + + begin + l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); + + for i in (with xpaths_tab as (select column_value xpath from table(l_pk_xpath_tabs)) + select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$') name + from xpaths_tab) + loop + l_sql_stmt := l_sql_stmt || case + when l_sql_stmt is null + then null + else ' or ' + end ||' a.'||i.name||q'[ is null or ]'||' e.'||i.name||q'[ is null]'; + end loop; + return l_sql_stmt; + end; + end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index e992fd48b..e092576a8 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -19,6 +19,7 @@ create or replace package ut_compound_data_helper authid definer is gc_compare_join_by constant varchar2(10):='join_by'; gc_compare_unordered constant varchar2(10):='unordered'; gc_compare_normal constant varchar2(10):='normal'; + gc_compare_sql constant varchar2(10):='sql'; type t_column_diffs is record( diff_type varchar2(1), @@ -61,12 +62,12 @@ create or replace package ut_compound_data_helper authid definer is function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob; - function compare_type(a_join_by_xpath in varchar2,a_unordered boolean) return varchar2; + function compare_type(a_join_by_xpath in varchar2,a_unordered boolean, a_is_sql_diffable integer := 0) return varchar2; function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unorderdered boolean + a_join_by_xpath varchar2,a_unorderdered boolean, a_is_sql_diffable integer ) return tt_row_diffs; subtype t_hash is raw(128); @@ -85,6 +86,15 @@ create or replace package ut_compound_data_helper authid definer is procedure update_row_and_pk_hash(a_self_data_id in raw, a_other_data_id in raw, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2); + + function generate_xmltab_stmt (a_column_info xmltype) return varchar2; + + function generate_equal_sql (a_column_info xmltype) return varchar2; + function generate_not_equal_sql (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2; + + function generate_join_by_on_stmt (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2; + + function generate_join_null_sql (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2; end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 49fe272eb..5dc099189 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -88,14 +88,18 @@ create or replace type body ut_compound_data_value as l_diff_id ut_compound_data_helper.t_hash; l_row_diffs ut_compound_data_helper.tt_row_diffs; l_compare_type varchar2(10); + l_self ut_compound_data_value; + l_is_sql_diff integer := 0; function get_diff_message (a_row_diff ut_compound_data_helper.t_row_diffs,a_compare_type varchar2) return varchar2 is begin - if a_compare_type = ut_compound_data_helper.gc_compare_join_by and a_row_diff.pk_value is not null then + if a_compare_type in (ut_compound_data_helper.gc_compare_join_by,ut_compound_data_helper.gc_compare_sql) + and a_row_diff.pk_value is not null then return ' PK '||a_row_diff.pk_value||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; elsif a_compare_type = ut_compound_data_helper.gc_compare_join_by or a_compare_type = ut_compound_data_helper.gc_compare_normal then return ' Row No. '||a_row_diff.rn||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - elsif a_compare_type = ut_compound_data_helper.gc_compare_unordered then + elsif a_compare_type in (ut_compound_data_helper.gc_compare_unordered,ut_compound_data_helper.gc_compare_sql) + and a_row_diff.pk_value is null then return rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; end if; end; @@ -104,6 +108,11 @@ create or replace type body ut_compound_data_value as if not a_other is of (ut_compound_data_value) then raise value_error; end if; + + if self is of (ut_data_value_refcursor) then + l_is_sql_diff := treat(self as ut_data_value_refcursor).is_sql_diffable; + end if; + l_actual := treat(a_other as ut_compound_data_value); dbms_lob.createtemporary(l_result,true); @@ -112,14 +121,20 @@ create or replace type body ut_compound_data_value as l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); -- First tell how many rows are different - execute immediate 'select count('||case when a_join_by_xpath is not null then 'distinct pk_hash' else '*' end||') from ' - || l_ut_owner || '.ut_compound_data_diff_tmp - where diff_id = :diff_id' into l_diff_row_count using l_diff_id; + execute immediate 'select count(' + ||case when ( a_join_by_xpath is not null and l_is_sql_diff = 0 ) + then 'distinct pk_hash' + else '*' + end + ||') from '|| l_ut_owner || '.ut_compound_data_diff_tmp ' + ||'where diff_id = :diff_id' + into l_diff_row_count using l_diff_id; if l_diff_row_count > 0 then - l_compare_type := ut_compound_data_helper.compare_type(a_join_by_xpath,a_unordered); + l_compare_type := ut_compound_data_helper.compare_type(a_join_by_xpath,a_unordered, l_is_sql_diff); l_row_diffs := ut_compound_data_helper.get_rows_diff( - self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, a_include_xpath, a_join_by_xpath, a_unordered); + self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, + a_include_xpath, a_join_by_xpath, a_unordered, l_is_sql_diff); l_message := chr(10) ||'Rows: [ ' || l_diff_row_count ||' differences' || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end @@ -247,5 +262,71 @@ create or replace type body ut_compound_data_value as return l_result; end; + member function compare_implementation_by_sql(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_compare boolean := false) return integer is + l_compare_sql varchar2(32767); + l_ut_owner varchar2(250) := ut_utils.ut_owner; + l_actual ut_data_value_refcursor := treat(a_other as ut_data_value_refcursor); + l_diff_id ut_compound_data_helper.t_hash; + l_table_stmt varchar2(32767); + l_where_stmt varchar2(32767); + l_join_by_stmt varchar2(32767); + l_exec_sql varchar2(32767); + l_other ut_compound_data_value; + l_result integer; + begin + + -- TODO : Add column filters!!!! + l_other := treat(a_other as ut_compound_data_value); + l_table_stmt := ut_compound_data_helper.generate_xmltab_stmt(l_actual.columns_info); + l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); + + l_compare_sql := q'[with exp as (select xt.*,x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :self_guid) x,]' + ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' + ||l_table_stmt||q'[ ,item_data xmltype PATH '*' ) xt),]' + ||q'[act as (select xt.*, x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :other_guid) x,]' + ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' || + l_table_stmt||q'[ ,item_data xmltype PATH '*') xt)]'; + + if a_join_by_xpath is null then + -- If no key defined do the join on all columns + l_join_by_stmt := ut_compound_data_helper.generate_equal_sql(l_actual.columns_info); + l_compare_sql := l_compare_sql || q'[select a.item_data act_item_data, a.data_id act_data_id, e.item_data exp_item_data, e.data_id exp_data_id ]' + || q'[from act a full outer join exp e on ( ]' + ||l_join_by_stmt||q'[ ) where a.data_id is null or e.data_id is null]'; + else + -- If key defined do the join or these and where on diffrences + l_where_stmt := ut_compound_data_helper.generate_not_equal_sql(l_actual.columns_info, a_join_by_xpath); + --l_join_is_null := ut_compound_data_helper.generate_join_null_sql(l_actual.columns_info, a_join_by_xpath); + l_join_by_stmt := ut_compound_data_helper.generate_join_by_on_stmt (l_actual.columns_info, a_join_by_xpath); + l_compare_sql := l_compare_sql || 'select a.item_data act_item_data, a.data_id act_data_id,' + ||' e.item_data exp_item_data, e.data_id exp_data_id from act a full outer join exp e on ( ' + ||l_join_by_stmt||' ) ' + ||' where '|| + case + when l_where_stmt is null then + null + else + '( '||l_where_stmt||' ) or' + end + ||'( a.data_id is null or e.data_id is null )'; + end if; + + l_exec_sql := 'insert into ' || l_ut_owner || '.ut_compound_data_diff_tmp ' + ||'( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no )' + ||' select :diff_id, nvl2(act_item_data,xmlelement( name "ROW", act_item_data),null) act_item_data, act_data_id,' + ||' nvl2(exp_item_data,xmlelement( name "ROW", exp_item_data),null) exp_item_data, exp_data_id , rownum ' + ||'from ( '|| l_compare_sql ||')'; + + execute immediate l_exec_sql using l_diff_id, self.data_id,l_actual.data_id; + --result is OK only if both are same + if sql%rowcount = 0 and self.elements_count = l_other.elements_count then + l_result := 0; + else + l_result := 1; + end if; + return l_result; + + end; + end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tps b/source/expectations/data_values/ut_compound_data_value.tps index 51d88c6f8..76a3b09e8 100644 --- a/source/expectations/data_values/ut_compound_data_value.tps +++ b/source/expectations/data_values/ut_compound_data_value.tps @@ -45,6 +45,7 @@ create or replace type ut_compound_data_value force under ut_data_value( member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return clob, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2) return integer, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean , a_inclusion_compare boolean := false, a_is_negated boolean := false) return integer + a_unordered boolean , a_inclusion_compare boolean := false, a_is_negated boolean := false) return integer, + member function compare_implementation_by_sql(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_compare boolean := false) return integer ) not final not instantiable / diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb index b610ee13c..de8aa6614 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb @@ -6,7 +6,8 @@ create or replace package body ut_curr_usr_compound_helper is g_anytype_collection_name t_type_name_map; g_user_defined_type pls_integer := dbms_sql.user_defined_type; g_is_collection boolean := false; - + g_is_sql_diffable boolean := false; + procedure set_collection_state(a_is_collection boolean) is begin --Make sure that we set a g_is_collection only once so we dont reset from true to false. @@ -15,6 +16,28 @@ create or replace package body ut_curr_usr_compound_helper is end if; end; + procedure set_sql_diff_state(a_is_sql_diff boolean) is + begin + --Make sure that we set a g_is_collection only once so we dont reset from true to false. + if not g_is_sql_diffable then + g_is_sql_diffable := a_is_sql_diff; + end if; + end; + + function is_sql_compare_allowed(a_type_name varchar2) return boolean is + begin + --clob/blob/xmltype/object/nestedcursor/nestedtable + if a_type_name IN (g_anytype_name_map(dbms_types.typecode_blob), + g_anytype_name_map(dbms_types.typecode_clob), + g_anytype_name_map(dbms_types.typecode_bfile), + g_anytype_name_map(dbms_types.typecode_varray)) + then + return false; + else + return true; + end if; + end; + function get_column_type(a_desc_rec dbms_sql.desc_rec3, a_desc_user_types boolean := false) return ut_key_anyval_pair is l_data ut_data_value; l_result ut_key_anyval_pair; @@ -34,16 +57,26 @@ create or replace package body ut_curr_usr_compound_helper is begin if g_type_name_map.exists(a_desc_rec.col_type) then l_data := ut_data_value_varchar2(g_type_name_map(a_desc_rec.col_type)); + set_sql_diff_state(is_sql_compare_allowed(g_type_name_map(a_desc_rec.col_type))); /*If its a collection regardless is we want to describe user defined types we will return just a name and capture that name */ elsif a_desc_rec.col_type = g_user_defined_type and is_collection(a_desc_rec.col_schema_name,a_desc_rec.col_type_name) then l_data := ut_data_value_varchar2(a_desc_rec.col_schema_name||'.'||a_desc_rec.col_type_name); + set_sql_diff_state(false); set_collection_state(true); elsif a_desc_rec.col_type = g_user_defined_type and a_desc_user_types then - l_data :=ut_data_value_xmltype(get_user_defined_type(a_desc_rec.col_schema_name,a_desc_rec.col_type_name)); + if a_desc_rec.col_type_name = 'XMLTYPE' + then + l_data := ut_data_value_varchar2(a_desc_rec.col_type_name); + else + l_data :=ut_data_value_xmltype(get_user_defined_type(a_desc_rec.col_schema_name,a_desc_rec.col_type_name)); + end if; + set_sql_diff_state(false); elsif a_desc_rec.col_schema_name is not null and a_desc_rec.col_type_name is not null then l_data := ut_data_value_varchar2(a_desc_rec.col_schema_name||'.'||a_desc_rec.col_type_name); + set_sql_diff_state(false); end if; + return ut_key_anyval_pair(a_desc_rec.col_name,l_data); end; @@ -56,6 +89,7 @@ create or replace package body ut_curr_usr_compound_helper is l_result.extend; l_result(l_result.last) := get_column_type(a_columns_tab(i),a_desc_user_types); end loop; + return l_result; end; @@ -83,7 +117,8 @@ create or replace package body ut_curr_usr_compound_helper is a_cursor in out nocopy sys_refcursor, a_columns_info out nocopy xmltype, a_join_by_info out nocopy xmltype, - a_contains_collection out nocopy number + a_contains_collection out nocopy number, + a_is_sql_diffable out nocopy number ) is l_columns_info xmltype; l_join_by_info xmltype; @@ -110,6 +145,7 @@ create or replace package body ut_curr_usr_compound_helper is into a_columns_info,a_join_by_info from dual; a_contains_collection := ut_utils.boolean_to_int(g_is_collection); + a_is_sql_diffable := ut_utils.boolean_to_int(g_is_sql_diffable); end; function get_anytype_attribute_count (a_anytype anytype) return pls_integer is @@ -133,7 +169,7 @@ create or replace package body ut_curr_usr_compound_helper is schema_name => l_schema_name, type_name => l_type_name, version => l_version, - numelems => l_attributes); + numelems => l_attributes); return l_attributes; end; @@ -147,7 +183,11 @@ create or replace package body ut_curr_usr_compound_helper is l_csid pls_integer; l_csfrm pls_integer; l_attr_elt_type anytype; + l_attributes_cnt pls_integer; begin + l_attributes_cnt := NVL(get_anytype_attribute_count(a_anytype),0); + + if l_attributes_cnt > 0 then for i in 1..get_anytype_attribute_count(a_anytype) loop l_attribute_typecode := a_anytype.getAttrElemInfo( pos => i, --First attribute @@ -166,6 +206,9 @@ create or replace package body ut_curr_usr_compound_helper is set_collection_state(true); end if; end loop; + end if; + + return l_result; end; @@ -174,8 +217,7 @@ create or replace package body ut_curr_usr_compound_helper is l_anytype anytype; l_typecode pls_integer; l_result xmltype; - l_columns_tab ut_key_value_pairs := ut_key_value_pairs(); - + l_columns_tab ut_key_value_pairs := ut_key_value_pairs(); begin execute immediate 'declare l_v '||a_owner||'.'||a_type_name||'; diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pks b/source/expectations/data_values/ut_curr_usr_compound_helper.pks index d662f51f9..039b8bfe9 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pks +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pks @@ -4,7 +4,8 @@ create or replace package ut_curr_usr_compound_helper authid current_user is a_cursor in out nocopy sys_refcursor, a_columns_info out nocopy xmltype, a_join_by_info out nocopy xmltype, - a_contains_collection out nocopy number + a_contains_collection out nocopy number, + a_is_sql_diffable out nocopy number ); function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return xmltype; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 5266a90bf..e253abfc6 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -23,13 +23,15 @@ create or replace type body ut_data_value_refcursor as end; member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) is - c_bulk_rows constant integer := 1000; + c_bulk_rows constant integer := 5000; l_cursor sys_refcursor := a_value; l_ctx number; l_xml xmltype; l_current_date_format varchar2(4000); cursor_not_open exception; l_ut_owner varchar2(250) := ut_utils.ut_owner; + l_set_id integer := 1; + begin self.is_data_null := ut_utils.boolean_to_int(a_value is null); self.self_type := $$plsql_unit; @@ -38,11 +40,11 @@ create or replace type body ut_data_value_refcursor as if l_cursor is not null then if l_cursor%isopen then --Get some more info regarding cursor, including if it containts collection columns and what is their name - + ut_curr_usr_compound_helper.get_columns_info(l_cursor,self.columns_info,self.key_info, - self.contain_collection); - + self.contain_collection,self.is_sql_diffable); self.elements_count := 0; + -- We use DBMS_XMLGEN in order to: -- 1) be able to process data in bulks (set of rows) -- 2) be able to influence the ROWSET/ROW tags @@ -60,20 +62,35 @@ create or replace type body ut_data_value_refcursor as dbms_xmlgen.setNullHandling(l_ctx, dbms_xmlgen.empty_tag); dbms_xmlgen.setMaxRows(l_ctx, c_bulk_rows); - loop - l_xml := dbms_xmlgen.getxmltype(l_ctx); - - execute immediate - 'insert into ' || l_ut_owner || '.ut_compound_data_tmp(data_id, item_no, item_data) ' || - 'select :self_guid, :self_row_count + rownum, value(a) ' || - ' from table( xmlsequence( extract(:l_xml,''ROWSET/*'') ) ) a' - using in self.data_id, self.elements_count, l_xml; + if self.is_sql_diffable = 1 then + loop + l_xml := dbms_xmlgen.getxmltype(l_ctx); + exit when dbms_xmlgen.getNumRowsProcessed(l_ctx) = 0; - exit when sql%rowcount = 0; + self.elements_count := self.elements_count + dbms_xmlgen.getNumRowsProcessed(l_ctx); + execute immediate + 'insert into ' || l_ut_owner || '.ut_compound_data_tmp(data_id, item_no, item_data) ' || + 'values (:self_guid, :self_row_count, :l_xml)' + using in self.data_id, l_set_id, l_xml; + + l_set_id := l_set_id + 1; + end loop; + else + loop + l_xml := dbms_xmlgen.getxmltype(l_ctx); + execute immediate + 'insert into ' || l_ut_owner || '.ut_compound_data_tmp(data_id, item_no, item_data) ' || + 'select :self_guid, :self_row_count + rownum, value(a) ' || + ' from table( xmlsequence( extract(:l_xml,''ROWSET/*'') ) ) a' + using in self.data_id, self.elements_count, l_xml; - self.elements_count := self.elements_count + sql%rowcount; - end loop; - + exit when sql%rowcount = 0; + + self.elements_count := self.elements_count + sql%rowcount; + end loop; + + end if; + ut_expectation_processor.reset_nls_params(); if l_cursor%isopen then close l_cursor; @@ -250,8 +267,15 @@ create or replace type body ut_data_value_refcursor as end if; if a_unordered then - l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, - a_join_by_xpath, a_unordered, a_inclusion_compare, a_is_negated); + if self.is_sql_diffable = 1 then + --TODO: :Treat unorder as pk by on all rows + l_result := l_result + (self as ut_compound_data_value).compare_implementation_by_sql(a_other, a_exclude_xpath, a_include_xpath, + a_join_by_xpath, a_inclusion_compare); + else + --We will make a decision about type of data inside whether we dump into table or do normal row by row + l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, + a_join_by_xpath, a_unordered, a_inclusion_compare); + end if; else l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath); end if; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 36c231887..5972f710c 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -40,6 +40,12 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( */ key_info xmltype, + /** + * Hold info if type contain any of the nonstandard user types which defines way we do compare later. + * Types of clob/blob/xmltype/object/nestedcursor/nestedtable will force into hash + */ + is_sql_diffable number(1,0), + constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) return self as result, member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), overriding member function to_string return varchar2, diff --git a/test/install_and_run_tests.sh b/test/install_and_run_tests.sh index b8aba77e2..80a777c10 100644 --- a/test/install_and_run_tests.sh +++ b/test/install_and_run_tests.sh @@ -30,6 +30,7 @@ time "$SQLCLI" ${UT3_TESTER}/${UT3_TESTER_PASSWORD}@//${CONNECTION_STR} @install cd .. + time utPLSQL-cli/bin/utplsql run ${UT3_TESTER}/${UT3_TESTER_PASSWORD}@${CONNECTION_STR} \ -source_path=source -owner=ut3 \ -test_path=test -c \ From 9741948bbad71506ab57189307a2512ae0d35b6c Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 4 Nov 2018 20:49:08 +0000 Subject: [PATCH 33/83] Added belt and braces for big cartesian --- .../data_values/ut_compound_data_diff_tmp.sql | 4 +- .../data_values/ut_compound_data_helper.pkb | 8 ++- .../data_values/ut_compound_data_value.tpb | 52 ++++++++++++++++--- 3 files changed, 53 insertions(+), 11 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_diff_tmp.sql b/source/expectations/data_values/ut_compound_data_diff_tmp.sql index c285d78fd..5fdb53e10 100644 --- a/source/expectations/data_values/ut_compound_data_diff_tmp.sql +++ b/source/expectations/data_values/ut_compound_data_diff_tmp.sql @@ -15,8 +15,8 @@ create global temporary table ut_compound_data_diff_tmp( diff_id raw(128), act_data_id raw(32), exp_data_id raw(32), - act_item_data xmltype, - exp_item_data xmltype, + act_item_data clob, + exp_item_data clob, item_no integer, pk_hash raw(128), item_hash raw(128), diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index eaa24d1f6..7f48e4262 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -174,12 +174,14 @@ create or replace package body ut_compound_data_helper is ) return tt_row_diffs is l_column_filter varchar2(32767); l_results tt_row_diffs; + t1 integer; begin l_column_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath); + t1 := dbms_utility.get_time; execute immediate q'[with diff_info as ( select act_data_id, exp_data_id, - act_item_data,exp_item_data, :join_by join_by, item_no + xmltype(act_item_data) act_item_data, xmltype(exp_item_data) exp_item_data, :join_by join_by, item_no from ut_compound_data_diff_tmp where diff_id = :diff_id ), exp as ( @@ -211,7 +213,9 @@ create or replace package body ut_compound_data_helper is where act_data_id is null or exp_data_id is null]' bulk collect into l_results using a_join_by_xpath, a_diff_id, a_expected_dataset_guid,a_actual_dataset_guid; - + + dbms_output.put_line((dbms_utility.get_time - t1)/100 || ' seconds - get col info'); + return l_results; end; diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 5dc099189..4730f23d4 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -263,16 +263,36 @@ create or replace type body ut_compound_data_value as end; member function compare_implementation_by_sql(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_compare boolean := false) return integer is - l_compare_sql varchar2(32767); + l_ut_owner varchar2(250) := ut_utils.ut_owner; l_actual ut_data_value_refcursor := treat(a_other as ut_data_value_refcursor); l_diff_id ut_compound_data_helper.t_hash; + + --Variable for dynamic SQL - to review and simplify ?? l_table_stmt varchar2(32767); l_where_stmt varchar2(32767); l_join_by_stmt varchar2(32767); l_exec_sql varchar2(32767); + l_compare_sql varchar2(32767); + l_other ut_compound_data_value; l_result integer; + --Max rows to prevent out of memory for too much diffs especially on join by non unique + l_max_rows integer := greatest(self.elements_count,1000); + l_loop_curs sys_refcursor; + type t_diff_rec is record ( + act_item_data clob, + act_data_id raw(32), + exp_item_data clob, + exp_data_id raw(32), + item_no integer + ); + type t_diff_tab is table of t_diff_rec; + l_diff_tab t_diff_tab; + + --TEST + t1 pls_integer; + begin -- TODO : Add column filters!!!! @@ -290,7 +310,7 @@ create or replace type body ut_compound_data_value as if a_join_by_xpath is null then -- If no key defined do the join on all columns l_join_by_stmt := ut_compound_data_helper.generate_equal_sql(l_actual.columns_info); - l_compare_sql := l_compare_sql || q'[select a.item_data act_item_data, a.data_id act_data_id, e.item_data exp_item_data, e.data_id exp_data_id ]' + l_compare_sql := l_compare_sql || q'[select xmlelement( name "ROW", a.item_data) act_item_data, a.data_id act_data_id, xmlelement( name "ROW", e.item_data) exp_item_data, e.data_id exp_data_id, rownum item_no ]' || q'[from act a full outer join exp e on ( ]' ||l_join_by_stmt||q'[ ) where a.data_id is null or e.data_id is null]'; else @@ -298,8 +318,8 @@ create or replace type body ut_compound_data_value as l_where_stmt := ut_compound_data_helper.generate_not_equal_sql(l_actual.columns_info, a_join_by_xpath); --l_join_is_null := ut_compound_data_helper.generate_join_null_sql(l_actual.columns_info, a_join_by_xpath); l_join_by_stmt := ut_compound_data_helper.generate_join_by_on_stmt (l_actual.columns_info, a_join_by_xpath); - l_compare_sql := l_compare_sql || 'select a.item_data act_item_data, a.data_id act_data_id,' - ||' e.item_data exp_item_data, e.data_id exp_data_id from act a full outer join exp e on ( ' + l_compare_sql := l_compare_sql || 'select xmlserialize(content (xmlelement( name "ROW", a.item_data)) no indent) act_item_data, a.data_id act_data_id,' + ||' xmlserialize(content (xmlelement( name "ROW", e.item_data)) no indent) exp_item_data, e.data_id exp_data_id, rownum item_no from act a full outer join exp e on ( ' ||l_join_by_stmt||' ) ' ||' where '|| case @@ -313,11 +333,29 @@ create or replace type body ut_compound_data_value as l_exec_sql := 'insert into ' || l_ut_owner || '.ut_compound_data_diff_tmp ' ||'( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no )' - ||' select :diff_id, nvl2(act_item_data,xmlelement( name "ROW", act_item_data),null) act_item_data, act_data_id,' - ||' nvl2(exp_item_data,xmlelement( name "ROW", exp_item_data),null) exp_item_data, exp_data_id , rownum ' + ||' select :diff_id, act_item_data, act_data_id,' + ||' exp_item_data, exp_data_id , item_no ' ||'from ( '|| l_compare_sql ||')'; - execute immediate l_exec_sql using l_diff_id, self.data_id,l_actual.data_id; + open l_loop_curs for l_compare_sql using self.data_id,l_actual.data_id; + + loop + fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; + exit when l_diff_tab.count = 0; + --Pass it to helper as authid as definer + t1 := dbms_utility.get_time; + + forall idx in 1..l_diff_tab.count + insert into ut3.ut_compound_data_diff_tmp + ( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no ) + values + (l_diff_id, l_diff_tab(idx).act_item_data, l_diff_tab(idx).act_data_id, l_diff_tab(idx).exp_item_data, l_diff_tab(idx).exp_data_id,l_diff_tab(idx).item_no); + dbms_output.put_line((dbms_utility.get_time - t1)/100 || ' seconds - get col info'); + --Exit after first fetch of max rows (to look later) + exit; + end loop; + + --execute immediate l_exec_sql using l_diff_id, self.data_id,l_actual.data_id; --result is OK only if both are same if sql%rowcount = 0 and self.elements_count = l_other.elements_count then l_result := 0; From be55366ded0dd27a30cd3d6861e6a1bef77bd086 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Mon, 5 Nov 2018 14:09:23 +0000 Subject: [PATCH 34/83] Inserting only first max display rows --- source/core/ut_utils.pks | 3 ++ .../data_values/ut_compound_data_helper.pkb | 9 ++++ .../data_values/ut_compound_data_helper.pks | 12 +++++ .../data_values/ut_compound_data_value.tpb | 53 +++++++++---------- 4 files changed, 50 insertions(+), 27 deletions(-) diff --git a/source/core/ut_utils.pks b/source/core/ut_utils.pks index 60f189a66..99ca0ed16 100644 --- a/source/core/ut_utils.pks +++ b/source/core/ut_utils.pks @@ -126,6 +126,9 @@ create or replace package ut_utils authid definer is gc_null_string constant varchar2(4) := 'NULL'; gc_empty_string constant varchar2(5) := 'EMPTY'; + gc_bc_fetch_limit constant integer := 1000; + gc_diff_max_rows constant integer := 20; + type t_version is record( major natural, minor natural, diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 7f48e4262..3d57100aa 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -863,5 +863,14 @@ create or replace package body ut_compound_data_helper is return l_sql_stmt; end; + procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw) is + begin + forall idx in 1..a_diff_tab.count + insert into ut3.ut_compound_data_diff_tmp + ( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no ) + values + (a_diff_id, a_diff_tab(idx).act_item_data, a_diff_tab(idx).act_data_id, a_diff_tab(idx).exp_item_data, a_diff_tab(idx).exp_data_id,a_diff_tab(idx).item_no); + end; + end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index e092576a8..96887a01f 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -49,6 +49,15 @@ create or replace package ut_compound_data_helper authid definer is type tt_row_diffs is table of t_row_diffs; + type t_diff_rec is record ( + act_item_data clob, + act_data_id raw(32), + exp_item_data clob, + exp_data_id raw(32), + item_no integer + ); + type t_diff_tab is table of t_diff_rec; + function get_column_info_xml(a_column_details ut_key_anyval_pair) return xmltype; function get_columns_filter( @@ -96,5 +105,8 @@ create or replace package ut_compound_data_helper authid definer is function generate_join_by_on_stmt (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2; function generate_join_null_sql (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2; + + procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw); + end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 4730f23d4..022022aa1 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -78,7 +78,7 @@ create or replace type body ut_compound_data_value as member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return clob is - c_max_rows constant integer := 20; + c_max_rows integer := ut_utils.gc_diff_max_rows; l_result clob; l_results ut_utils.t_clob_tab := ut_utils.t_clob_tab(); l_message varchar2(32767); @@ -269,27 +269,21 @@ create or replace type body ut_compound_data_value as l_diff_id ut_compound_data_helper.t_hash; --Variable for dynamic SQL - to review and simplify ?? - l_table_stmt varchar2(32767); - l_where_stmt varchar2(32767); - l_join_by_stmt varchar2(32767); - l_exec_sql varchar2(32767); - l_compare_sql varchar2(32767); + l_table_stmt clob; + l_where_stmt clob; + l_join_by_stmt clob; + l_exec_sql clob; + l_compare_sql clob; l_other ut_compound_data_value; l_result integer; - --Max rows to prevent out of memory for too much diffs especially on join by non unique - l_max_rows integer := greatest(self.elements_count,1000); - l_loop_curs sys_refcursor; - type t_diff_rec is record ( - act_item_data clob, - act_data_id raw(32), - exp_item_data clob, - exp_data_id raw(32), - item_no integer - ); - type t_diff_tab is table of t_diff_rec; - l_diff_tab t_diff_tab; + --We will start with number od differences being displayed. + l_max_rows integer := ut_utils.gc_diff_max_rows; + l_loop_curs sys_refcursor; + l_diff_tab ut_compound_data_helper.t_diff_tab; + l_sql_rowcount integer :=0; + --TEST t1 pls_integer; @@ -345,19 +339,24 @@ create or replace type body ut_compound_data_value as --Pass it to helper as authid as definer t1 := dbms_utility.get_time; - forall idx in 1..l_diff_tab.count - insert into ut3.ut_compound_data_diff_tmp - ( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no ) - values - (l_diff_id, l_diff_tab(idx).act_item_data, l_diff_tab(idx).act_data_id, l_diff_tab(idx).exp_item_data, l_diff_tab(idx).exp_data_id,l_diff_tab(idx).item_no); - dbms_output.put_line((dbms_utility.get_time - t1)/100 || ' seconds - get col info'); - --Exit after first fetch of max rows (to look later) - exit; + if (ut_utils.gc_diff_max_rows > l_sql_rowcount ) then + ut_compound_data_helper.insert_diffs_result(l_diff_tab,l_diff_id); + end if; + + l_sql_rowcount := l_sql_rowcount + l_diff_tab.count; + + if (ut_utils.gc_diff_max_rows <= l_sql_rowcount and l_max_rows != ut_utils.gc_bc_fetch_limit ) then + l_max_rows := ut_utils.gc_bc_fetch_limit; + end if; + + dbms_output.put_line((dbms_utility.get_time - t1)/100 || ' seconds - get col info , values'||l_sql_rowcount); end loop; + --l_actual.set_difference_count(l_sql_rowcount); + --execute immediate l_exec_sql using l_diff_id, self.data_id,l_actual.data_id; --result is OK only if both are same - if sql%rowcount = 0 and self.elements_count = l_other.elements_count then + if l_sql_rowcount = 0 and self.elements_count = l_other.elements_count then l_result := 0; else l_result := 1; From ae3d34f820d26af5ccc3f3ec1c142828a29680c3 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Mon, 5 Nov 2018 17:25:12 +0000 Subject: [PATCH 35/83] Remove clob transformation --- source/expectations/data_values/ut_compound_data_diff_tmp.sql | 4 ++-- source/expectations/data_values/ut_compound_data_helper.pkb | 4 ++-- source/expectations/data_values/ut_compound_data_helper.pks | 4 ++-- source/expectations/data_values/ut_compound_data_value.tpb | 4 ++-- 4 files changed, 8 insertions(+), 8 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_diff_tmp.sql b/source/expectations/data_values/ut_compound_data_diff_tmp.sql index 5fdb53e10..c285d78fd 100644 --- a/source/expectations/data_values/ut_compound_data_diff_tmp.sql +++ b/source/expectations/data_values/ut_compound_data_diff_tmp.sql @@ -15,8 +15,8 @@ create global temporary table ut_compound_data_diff_tmp( diff_id raw(128), act_data_id raw(32), exp_data_id raw(32), - act_item_data clob, - exp_item_data clob, + act_item_data xmltype, + exp_item_data xmltype, item_no integer, pk_hash raw(128), item_hash raw(128), diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 3d57100aa..119c8be7c 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -181,7 +181,7 @@ create or replace package body ut_compound_data_helper is execute immediate q'[with diff_info as ( select act_data_id, exp_data_id, - xmltype(act_item_data) act_item_data, xmltype(exp_item_data) exp_item_data, :join_by join_by, item_no + act_item_data act_item_data, exp_item_data exp_item_data, :join_by join_by, item_no from ut_compound_data_diff_tmp where diff_id = :diff_id ), exp as ( @@ -869,7 +869,7 @@ create or replace package body ut_compound_data_helper is insert into ut3.ut_compound_data_diff_tmp ( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no ) values - (a_diff_id, a_diff_tab(idx).act_item_data, a_diff_tab(idx).act_data_id, a_diff_tab(idx).exp_item_data, a_diff_tab(idx).exp_data_id,a_diff_tab(idx).item_no); + (a_diff_id, xmlelement( name "ROW", a_diff_tab(idx).act_item_data), a_diff_tab(idx).act_data_id,xmlelement( name "ROW", a_diff_tab(idx).exp_item_data), a_diff_tab(idx).exp_data_id,a_diff_tab(idx).item_no); end; end; diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 96887a01f..a0aaaea91 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -50,9 +50,9 @@ create or replace package ut_compound_data_helper authid definer is type tt_row_diffs is table of t_row_diffs; type t_diff_rec is record ( - act_item_data clob, + act_item_data xmltype, act_data_id raw(32), - exp_item_data clob, + exp_item_data xmltype, exp_data_id raw(32), item_no integer ); diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 022022aa1..8b6b15aee 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -312,8 +312,8 @@ create or replace type body ut_compound_data_value as l_where_stmt := ut_compound_data_helper.generate_not_equal_sql(l_actual.columns_info, a_join_by_xpath); --l_join_is_null := ut_compound_data_helper.generate_join_null_sql(l_actual.columns_info, a_join_by_xpath); l_join_by_stmt := ut_compound_data_helper.generate_join_by_on_stmt (l_actual.columns_info, a_join_by_xpath); - l_compare_sql := l_compare_sql || 'select xmlserialize(content (xmlelement( name "ROW", a.item_data)) no indent) act_item_data, a.data_id act_data_id,' - ||' xmlserialize(content (xmlelement( name "ROW", e.item_data)) no indent) exp_item_data, e.data_id exp_data_id, rownum item_no from act a full outer join exp e on ( ' + l_compare_sql := l_compare_sql || 'select a.item_data act_item_data, a.data_id act_data_id,' + ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no from act a full outer join exp e on ( ' ||l_join_by_stmt||' ) ' ||' where '|| case From b4113fd13e71eb2782eb16cefacc01feb572fc89 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Tue, 6 Nov 2018 07:42:02 +0000 Subject: [PATCH 36/83] Check in progress of working version. Still to define include and exclude. --- source/api/ut_runner.pkb | 1 + .../data_values/ut_compound_data_helper.pkb | 18 ++++++++++++- .../data_values/ut_compound_data_helper.pks | 6 +++++ .../data_values/ut_compound_data_value.tpb | 25 ++++++++----------- .../data_values/ut_compound_data_value.tps | 2 +- .../expectations/test_expectations_cursor.pkb | 14 +++++------ 6 files changed, 43 insertions(+), 23 deletions(-) diff --git a/source/api/ut_runner.pkb b/source/api/ut_runner.pkb index c04fa5112..39862de61 100644 --- a/source/api/ut_runner.pkb +++ b/source/api/ut_runner.pkb @@ -49,6 +49,7 @@ create or replace package body ut_runner is ut_metadata.reset_source_definition_cache; ut_utils.read_cache_to_dbms_output(); ut_coverage_helper.cleanup_tmp_table(); + ut_compound_data_helper.cleanup_diff(); end; diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 119c8be7c..a07f15fdd 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -17,6 +17,7 @@ create or replace package body ut_compound_data_helper is */ g_user_defined_type pls_integer := dbms_sql.user_defined_type; + gc_diff_count integer; function get_column_info_xml(a_column_details ut_key_anyval_pair) return xmltype is l_result varchar2(4000); @@ -822,7 +823,7 @@ create or replace package body ut_compound_data_helper is where not exists (select 1 from pk_names p where lower(p.name) = lower(xt.name)) ) loop - l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' or ' end ||' a.'||i.name||q'[ <> ]'||' e.'||i.name; + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' or ' end ||' (decode(a.'||i.name||','||' e.'||i.name||',1,0) = 0)'; end loop; return l_sql_stmt; end; @@ -872,5 +873,20 @@ create or replace package body ut_compound_data_helper is (a_diff_id, xmlelement( name "ROW", a_diff_tab(idx).act_item_data), a_diff_tab(idx).act_data_id,xmlelement( name "ROW", a_diff_tab(idx).exp_item_data), a_diff_tab(idx).exp_data_id,a_diff_tab(idx).item_no); end; + procedure set_rows_diff(a_rows_diff integer) is + begin + gc_diff_count := a_rows_diff; + end; + + procedure cleanup_diff is + begin + gc_diff_count := 0; + end; + + function get_rows_diff return integer is + begin + return gc_diff_count; + end; + end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index a0aaaea91..9fe410647 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -108,5 +108,11 @@ create or replace package ut_compound_data_helper authid definer is procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw); + procedure set_rows_diff(a_rows_diff integer); + + procedure cleanup_diff; + + function get_rows_diff return integer; + end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 8b6b15aee..cf3caf911 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -121,7 +121,12 @@ create or replace type body ut_compound_data_value as l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); -- First tell how many rows are different - execute immediate 'select count(' + + --REDO that is a bit mess ?? + if l_is_sql_diff = 1 then + l_diff_row_count := ut_compound_data_helper.get_rows_diff; + else + execute immediate 'select count(' ||case when ( a_join_by_xpath is not null and l_is_sql_diff = 0 ) then 'distinct pk_hash' else '*' @@ -129,7 +134,8 @@ create or replace type body ut_compound_data_value as ||') from '|| l_ut_owner || '.ut_compound_data_diff_tmp ' ||'where diff_id = :diff_id' into l_diff_row_count using l_diff_id; - + end if; + if l_diff_row_count > 0 then l_compare_type := ut_compound_data_helper.compare_type(a_join_by_xpath,a_unordered, l_is_sql_diff); l_row_diffs := ut_compound_data_helper.get_rows_diff( @@ -324,12 +330,6 @@ create or replace type body ut_compound_data_value as end ||'( a.data_id is null or e.data_id is null )'; end if; - - l_exec_sql := 'insert into ' || l_ut_owner || '.ut_compound_data_diff_tmp ' - ||'( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no )' - ||' select :diff_id, act_item_data, act_data_id,' - ||' exp_item_data, exp_data_id , item_no ' - ||'from ( '|| l_compare_sql ||')'; open l_loop_curs for l_compare_sql using self.data_id,l_actual.data_id; @@ -337,8 +337,7 @@ create or replace type body ut_compound_data_value as fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; exit when l_diff_tab.count = 0; --Pass it to helper as authid as definer - t1 := dbms_utility.get_time; - + if (ut_utils.gc_diff_max_rows > l_sql_rowcount ) then ut_compound_data_helper.insert_diffs_result(l_diff_tab,l_diff_id); end if; @@ -349,12 +348,10 @@ create or replace type body ut_compound_data_value as l_max_rows := ut_utils.gc_bc_fetch_limit; end if; - dbms_output.put_line((dbms_utility.get_time - t1)/100 || ' seconds - get col info , values'||l_sql_rowcount); end loop; + + ut_compound_data_helper.set_rows_diff(l_sql_rowcount); - --l_actual.set_difference_count(l_sql_rowcount); - - --execute immediate l_exec_sql using l_diff_id, self.data_id,l_actual.data_id; --result is OK only if both are same if l_sql_rowcount = 0 and self.elements_count = l_other.elements_count then l_result := 0; diff --git a/source/expectations/data_values/ut_compound_data_value.tps b/source/expectations/data_values/ut_compound_data_value.tps index 76a3b09e8..97370eea6 100644 --- a/source/expectations/data_values/ut_compound_data_value.tps +++ b/source/expectations/data_values/ut_compound_data_value.tps @@ -34,7 +34,7 @@ create or replace type ut_compound_data_value force under ut_data_value( * Holds unique id for retrieving the data from ut_compound_data_tmp temp table */ data_id raw(16), - + overriding member function get_object_info return varchar2, overriding member function is_null return boolean, overriding member function is_diffable return boolean, diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 04bbbe5d9..00236f99e 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -1087,13 +1087,13 @@ Rows: [ 2 differences ]% l_expected SYS_REFCURSOR; begin --Arrange - open l_actual for select owner, object_name,object_type from all_objects where owner = user + open l_actual for select object_id, owner, object_name,object_type from all_objects where owner = user order by 1,2,3 asc; - open l_expected for select owner, object_name,object_type from all_objects where owner = user + open l_expected for select object_id, owner, object_name,object_type from all_objects where owner = user order by 1,2,3 desc; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OWNER'); + ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OBJECT_ID'); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; @@ -1109,7 +1109,7 @@ Rows: [ 2 differences ]% order by 1,2,3 desc; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).join_by(ut3.ut_varchar2_list('OWNER,OBJECT_NAME')); + ut3.ut.expect(l_actual).to_equal(l_expected).join_by(ut3.ut_varchar2_list('OBJECT_NAME,OBJECT_TYPE')); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; @@ -1257,10 +1257,10 @@ Diff:% l_expected SYS_REFCURSOR; begin --Arrange - open l_actual for select object_name from all_objects where rownum <=1100; - open l_expected for select object_name from all_objects where rownum <=1100; + open l_actual for select level object_id, level || '_TEST' object_name from dual connect by level <=1100; + open l_expected for select level object_id, level || '_TEST' object_name from dual connect by level <=1100; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OBJECT_NAME'); + ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OBJECT_ID'); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; From 816a1c1a17a49c770318e91338563d38bccfbe49 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Tue, 6 Nov 2018 13:25:20 +0000 Subject: [PATCH 37/83] Beautify sql generation --- .../data_values/ut_compound_data_helper.pkb | 198 ++++++++++-------- .../data_values/ut_compound_data_helper.pks | 13 +- .../data_values/ut_compound_data_value.tpb | 61 +----- 3 files changed, 125 insertions(+), 147 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index a07f15fdd..245a8b525 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -175,10 +175,8 @@ create or replace package body ut_compound_data_helper is ) return tt_row_diffs is l_column_filter varchar2(32767); l_results tt_row_diffs; - t1 integer; begin l_column_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath); - t1 := dbms_utility.get_time; execute immediate q'[with diff_info as ( select act_data_id, exp_data_id, @@ -214,9 +212,7 @@ create or replace package body ut_compound_data_helper is where act_data_id is null or exp_data_id is null]' bulk collect into l_results using a_join_by_xpath, a_diff_id, a_expected_dataset_guid,a_actual_dataset_guid; - - dbms_output.put_line((dbms_utility.get_time - t1)/100 || ' seconds - get col info'); - + return l_results; end; @@ -765,105 +761,141 @@ create or replace package body ut_compound_data_helper is return l_sql; end; - function generate_xmltab_stmt (a_column_info xmltype) return varchar2 is - l_sql_stmt varchar2(32767); - begin - for i in (select /*+ CARDINALITY(xt 100) */ - xt.name - from (select a_column_info item_data from dual) x, - xmltable( - '/ROW/*' - passing x.item_data - columns - name varchar2(4000) PATH '@xml_valid_name' - ) xt) - loop - l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ',' end ||i.name||q'[ varchar2(4000) PATH ']'||i.name||q'[']'; + function generate_xmltab_stmt (a_column_info ut_varchar2_list, a_inc_filter ut_varchar2_list, a_exc_filter ut_varchar2_list) return clob is + l_sql_stmt clob; + begin + for i in 1..a_column_info.count loop + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ',' end ||a_column_info(i)||q'[ varchar2(4000) PATH ']'||a_column_info(i)||q'[']'; end loop; return l_sql_stmt; end; - - function generate_equal_sql (a_column_info xmltype) return varchar2 is - l_sql_stmt varchar2(32767); + + function generate_equal_sql (a_column_info ut_varchar2_list, a_inc_filter ut_varchar2_list, a_exc_filter ut_varchar2_list) return clob is + l_sql_stmt clob; begin - for i in (select /*+ CARDINALITY(xt 100) */ - xt.name - from (select a_column_info item_data from dual) x, - xmltable( - '/ROW/*' - passing x.item_data - columns - name varchar2(4000) PATH '@xml_valid_name' - ) xt) + for i in 1..a_column_info.count loop + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||a_column_info(i)||q'[ = ]'||' e.'||a_column_info(i); + end loop; + + return l_sql_stmt; + end; + + function generate_join_by_on_stmt (a_join_by_xpath_tab ut_varchar2_list) return clob is + l_sql_stmt clob; + begin + for i in (with xpaths_tab as (select column_value xpath from table(a_join_by_xpath_tab)) + select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$') name + from xpaths_tab) loop l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.name||q'[ = ]'||' e.'||i.name; end loop; return l_sql_stmt; end; - - function generate_not_equal_sql (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2 is - l_sql_stmt varchar2(32767); - l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); - begin - l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); - + + function generate_not_equal_sql (a_column_info ut_varchar2_list, a_join_by_xpath ut_varchar2_list) return clob is + l_sql_stmt clob; + begin for i in ( - with xpaths_tab as (select column_value xpath from table(l_pk_xpath_tabs)), + with xpaths_tab as (select column_value xpath from table(a_join_by_xpath)), pk_names as (select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$') name from xpaths_tab) - select /*+ CARDINALITY(xt 100) */ - xt.name - from (select a_column_info item_data from dual) x, - xmltable( - '/ROW/*' - passing x.item_data - columns - name varchar2(4000) PATH '@xml_valid_name' - ) xt - where not exists (select 1 from pk_names p where lower(p.name) = lower(xt.name)) - ) + select /*+ CARDINALITY(xt 100) */ + column_value as name + from table(a_column_info) xt + where not exists (select 1 from pk_names p where lower(p.name) = lower(xt.column_value)) + ) loop l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' or ' end ||' (decode(a.'||i.name||','||' e.'||i.name||',1,0) = 0)'; end loop; return l_sql_stmt; - end; + end; - function generate_join_by_on_stmt (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2 is - l_sql_stmt varchar2(32767); - l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); + function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, + a_include_xpath varchar2, a_join_by_xpath varchar2) return clob is + l_compare_sql clob; + l_column_filter varchar2(32767); + l_temp_string varchar2(32767); - begin - l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); - - for i in (with xpaths_tab as (select column_value xpath from table(l_pk_xpath_tabs)) - select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$') name - from xpaths_tab) - loop - l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.name||q'[ = ]'||' e.'||i.name; - end loop; - return l_sql_stmt; - end; - - function generate_join_null_sql (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2 is - l_sql_stmt varchar2(32767); l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); + l_xpath_inc_tab ut_varchar2_list := ut_varchar2_list(); + l_xpath_exc_tab ut_varchar2_list := ut_varchar2_list(); + l_col_info_tab ut_varchar2_list := ut_varchar2_list(); + + l_ut_owner varchar2(250) := ut_utils.ut_owner; + l_xmltable_stmt clob; + l_where_stmt clob; + function get_columns_names (a_xpath_tab in ut_varchar2_list) return ut_varchar2_list is + l_names_tab ut_varchar2_list := ut_varchar2_list(); + begin + select REGEXP_SUBSTR (column_value,'[^(/\*/)](.+)$') + bulk collect into l_names_tab + from table(a_xpath_tab); + return l_names_tab; + end; + + function get_columns_info (a_columns_info in xmltype) return ut_varchar2_list is + l_columns_info ut_varchar2_list := ut_varchar2_list(); + begin + select /*+ CARDINALITY(xt 100) */ + xt.name + bulk collect into l_columns_info + from (select a_column_info item_data from dual) x, + xmltable( + '/ROW/*' + passing x.item_data + columns + name varchar2(4000) PATH '@xml_valid_name' + ) xt; + return l_columns_info; + end; + begin - l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); - - for i in (with xpaths_tab as (select column_value xpath from table(l_pk_xpath_tabs)) - select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$') name - from xpaths_tab) - loop - l_sql_stmt := l_sql_stmt || case - when l_sql_stmt is null - then null - else ' or ' - end ||' a.'||i.name||q'[ is null or ]'||' e.'||i.name||q'[ is null]'; - end loop; - return l_sql_stmt; - end; - + dbms_lob.createtemporary(l_compare_sql, true); + l_column_filter := ut_compound_data_helper.get_columns_filter(a_exclude_xpath, a_include_xpath); + l_pk_xpath_tabs := get_columns_names(ut_utils.string_to_table(a_join_by_xpath,'|')); + l_xpath_inc_tab := get_columns_names(ut_utils.string_to_table(a_include_xpath,'|')); + l_xpath_exc_tab := get_columns_names(ut_utils.string_to_table(a_exclude_xpath,'|')); + l_col_info_tab := get_columns_info(a_column_info); + l_xmltable_stmt := generate_xmltab_stmt(l_col_info_tab, l_xpath_inc_tab, l_xpath_exc_tab); + + l_temp_string := q'[with exp as (select ucd.*,x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :self_guid) x,]' + ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]'; + ut_utils.append_to_clob(l_compare_sql, l_temp_string); + ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt); + + l_temp_string := q'[ ,item_data xmltype PATH '*' ) ucd),]' + ||q'[act as (select ucd.*, x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :other_guid) x,]' + ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' ; + ut_utils.append_to_clob(l_compare_sql,l_temp_string); + ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt||q'[ ,item_data xmltype PATH '*') ucd)]'); + + if a_join_by_xpath is null then + -- If no key defined do the join on all columns + l_temp_string := q'[select xmlelement( name "ROW", a.item_data) act_item_data, a.data_id act_data_id, xmlelement( name "ROW", e.item_data) exp_item_data, e.data_id exp_data_id, rownum item_no ]' + || q'[from act a full outer join exp e on ( ]'; + ut_utils.append_to_clob(l_compare_sql,l_temp_string); + ut_utils.append_to_clob(l_compare_sql,ut_compound_data_helper.generate_equal_sql(l_col_info_tab, l_xpath_inc_tab, l_xpath_exc_tab)||q'[ ) where a.data_id is null or e.data_id is null]'); + else + -- If key defined do the join or these and where on diffrences + l_temp_string := 'select a.item_data act_item_data, a.data_id act_data_id,' + ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no from act a full outer join exp e on ( '; + ut_utils.append_to_clob(l_compare_sql,l_temp_string); + + ut_utils.append_to_clob(l_compare_sql,ut_compound_data_helper.generate_join_by_on_stmt (l_pk_xpath_tabs)||' ) where '); + + l_where_stmt := ut_compound_data_helper.generate_not_equal_sql(l_col_info_tab, l_pk_xpath_tabs); + case + when l_where_stmt is null then + null; + else + ut_utils.append_to_clob(l_compare_sql,'( '||l_where_stmt||' ) or ( a.data_id is null or e.data_id is null )'); + end case; + end if; + + return l_compare_sql; + end; + procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw) is begin forall idx in 1..a_diff_tab.count diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 9fe410647..7c1933a16 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -96,16 +96,9 @@ create or replace package ut_compound_data_helper authid definer is procedure update_row_and_pk_hash(a_self_data_id in raw, a_other_data_id in raw, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2); - function generate_xmltab_stmt (a_column_info xmltype) return varchar2; - - function generate_equal_sql (a_column_info xmltype) return varchar2; - - function generate_not_equal_sql (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2; - - function generate_join_by_on_stmt (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2; - - function generate_join_null_sql (a_column_info xmltype, a_join_by_xpath varchar2) return varchar2; - + function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, + a_include_xpath varchar2, a_join_by_xpath varchar2) return clob; + procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw); procedure set_rows_diff(a_rows_diff integer); diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index cf3caf911..af8a4f748 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -270,17 +270,9 @@ create or replace type body ut_compound_data_value as member function compare_implementation_by_sql(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_compare boolean := false) return integer is - l_ut_owner varchar2(250) := ut_utils.ut_owner; l_actual ut_data_value_refcursor := treat(a_other as ut_data_value_refcursor); l_diff_id ut_compound_data_helper.t_hash; - - --Variable for dynamic SQL - to review and simplify ?? - l_table_stmt clob; - l_where_stmt clob; - l_join_by_stmt clob; - l_exec_sql clob; - l_compare_sql clob; - + l_other ut_compound_data_value; l_result integer; --We will start with number od differences being displayed. @@ -289,55 +281,18 @@ create or replace type body ut_compound_data_value as l_loop_curs sys_refcursor; l_diff_tab ut_compound_data_helper.t_diff_tab; l_sql_rowcount integer :=0; - - --TEST - t1 pls_integer; begin - -- TODO : Add column filters!!!! - l_other := treat(a_other as ut_compound_data_value); - l_table_stmt := ut_compound_data_helper.generate_xmltab_stmt(l_actual.columns_info); - l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - - l_compare_sql := q'[with exp as (select xt.*,x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :self_guid) x,]' - ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' - ||l_table_stmt||q'[ ,item_data xmltype PATH '*' ) xt),]' - ||q'[act as (select xt.*, x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :other_guid) x,]' - ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' || - l_table_stmt||q'[ ,item_data xmltype PATH '*') xt)]'; - - if a_join_by_xpath is null then - -- If no key defined do the join on all columns - l_join_by_stmt := ut_compound_data_helper.generate_equal_sql(l_actual.columns_info); - l_compare_sql := l_compare_sql || q'[select xmlelement( name "ROW", a.item_data) act_item_data, a.data_id act_data_id, xmlelement( name "ROW", e.item_data) exp_item_data, e.data_id exp_data_id, rownum item_no ]' - || q'[from act a full outer join exp e on ( ]' - ||l_join_by_stmt||q'[ ) where a.data_id is null or e.data_id is null]'; - else - -- If key defined do the join or these and where on diffrences - l_where_stmt := ut_compound_data_helper.generate_not_equal_sql(l_actual.columns_info, a_join_by_xpath); - --l_join_is_null := ut_compound_data_helper.generate_join_null_sql(l_actual.columns_info, a_join_by_xpath); - l_join_by_stmt := ut_compound_data_helper.generate_join_by_on_stmt (l_actual.columns_info, a_join_by_xpath); - l_compare_sql := l_compare_sql || 'select a.item_data act_item_data, a.data_id act_data_id,' - ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no from act a full outer join exp e on ( ' - ||l_join_by_stmt||' ) ' - ||' where '|| - case - when l_where_stmt is null then - null - else - '( '||l_where_stmt||' ) or' - end - ||'( a.data_id is null or e.data_id is null )'; - end if; - - open l_loop_curs for l_compare_sql using self.data_id,l_actual.data_id; - + l_other := treat(a_other as ut_compound_data_value); + l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); + + open l_loop_curs for ut_compound_data_helper.gen_compare_sql(l_actual.columns_info, a_exclude_xpath, + a_include_xpath, a_join_by_xpath) using self.data_id,l_actual.data_id; loop fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; exit when l_diff_tab.count = 0; --Pass it to helper as authid as definer - if (ut_utils.gc_diff_max_rows > l_sql_rowcount ) then ut_compound_data_helper.insert_diffs_result(l_diff_tab,l_diff_id); end if; @@ -347,11 +302,9 @@ create or replace type body ut_compound_data_value as if (ut_utils.gc_diff_max_rows <= l_sql_rowcount and l_max_rows != ut_utils.gc_bc_fetch_limit ) then l_max_rows := ut_utils.gc_bc_fetch_limit; end if; - end loop; - ut_compound_data_helper.set_rows_diff(l_sql_rowcount); - + ut_compound_data_helper.set_rows_diff(l_sql_rowcount); --result is OK only if both are same if l_sql_rowcount = 0 and self.elements_count = l_other.elements_count then l_result := 0; From e5de7d20a26ec576fd8d8937ba7632133cdfa074 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Tue, 6 Nov 2018 20:14:39 +0000 Subject: [PATCH 38/83] Tidy up Add include and exclude filters --- .../data_values/ut_compound_data_helper.pkb | 79 +++++++++++-------- .../data_values/ut_compound_data_value.tpb | 2 +- 2 files changed, 46 insertions(+), 35 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 245a8b525..6bfe0af6f 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -173,15 +173,18 @@ create or replace package body ut_compound_data_helper is a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2 ) return tt_row_diffs is - l_column_filter varchar2(32767); + + l_act_col_filter varchar2(32767); + l_exp_col_filter varchar2(32767); l_results tt_row_diffs; begin - l_column_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath); + l_act_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','act_item_data'); + l_exp_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','exp_item_data'); execute immediate q'[with diff_info as - ( select act_data_id, exp_data_id, - act_item_data act_item_data, exp_item_data exp_item_data, :join_by join_by, item_no - from ut_compound_data_diff_tmp + ( select act_data_id, exp_data_id,]' + ||l_act_col_filter||','|| l_exp_col_filter||q'[, :join_by join_by, item_no + from ut_compound_data_diff_tmp ucd where diff_id = :diff_id ), exp as ( select exp_item_data, exp_data_id, item_no rn,rownum col_no, @@ -206,12 +209,14 @@ create or replace package body ut_compound_data_helper is unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') ) union all select item_no as rn, case when exp_data_id is null then 'Extra' else 'Missing' end as diff_type, - xmlserialize(content nvl(exp_item_data, act_item_data) no indent) diffed_row, - nvl2(i.join_by,ut3.ut_compound_data_helper.get_pk_value(i.join_by,coalesce(exp_item_data,act_item_data)),null) pk_value + xmlserialize(content (case when exp_data_id is null then act_item_data else exp_item_data end) no indent) diffed_row, + nvl2(i.join_by,ut3.ut_compound_data_helper.get_pk_value(i.join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value from diff_info i where act_data_id is null or exp_data_id is null]' bulk collect into l_results - using a_join_by_xpath, a_diff_id, a_expected_dataset_guid,a_actual_dataset_guid; + using a_exclude_xpath,a_include_xpath, + a_exclude_xpath,a_include_xpath, + a_join_by_xpath, a_diff_id, a_expected_dataset_guid,a_actual_dataset_guid; return l_results; end; @@ -761,7 +766,7 @@ create or replace package body ut_compound_data_helper is return l_sql; end; - function generate_xmltab_stmt (a_column_info ut_varchar2_list, a_inc_filter ut_varchar2_list, a_exc_filter ut_varchar2_list) return clob is + function generate_xmltab_stmt (a_column_info ut_varchar2_list) return clob is l_sql_stmt clob; begin for i in 1..a_column_info.count loop @@ -770,7 +775,7 @@ create or replace package body ut_compound_data_helper is return l_sql_stmt; end; - function generate_equal_sql (a_column_info ut_varchar2_list, a_inc_filter ut_varchar2_list, a_exc_filter ut_varchar2_list) return clob is + function generate_equal_sql (a_column_info ut_varchar2_list) return clob is l_sql_stmt clob; begin for i in 1..a_column_info.count loop @@ -812,18 +817,15 @@ create or replace package body ut_compound_data_helper is function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2) return clob is - l_compare_sql clob; - l_column_filter varchar2(32767); - l_temp_string varchar2(32767); + l_compare_sql clob; + l_temp_string varchar2(32767); - l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); - l_xpath_inc_tab ut_varchar2_list := ut_varchar2_list(); - l_xpath_exc_tab ut_varchar2_list := ut_varchar2_list(); - l_col_info_tab ut_varchar2_list := ut_varchar2_list(); + l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); + l_act_col_tab ut_varchar2_list := ut_varchar2_list(); - l_ut_owner varchar2(250) := ut_utils.ut_owner; - l_xmltable_stmt clob; - l_where_stmt clob; + l_ut_owner varchar2(250) := ut_utils.ut_owner; + l_xmltable_stmt clob; + l_where_stmt clob; function get_columns_names (a_xpath_tab in ut_varchar2_list) return ut_varchar2_list is l_names_tab ut_varchar2_list := ut_varchar2_list(); @@ -852,12 +854,22 @@ create or replace package body ut_compound_data_helper is begin dbms_lob.createtemporary(l_compare_sql, true); - l_column_filter := ut_compound_data_helper.get_columns_filter(a_exclude_xpath, a_include_xpath); - l_pk_xpath_tabs := get_columns_names(ut_utils.string_to_table(a_join_by_xpath,'|')); - l_xpath_inc_tab := get_columns_names(ut_utils.string_to_table(a_include_xpath,'|')); - l_xpath_exc_tab := get_columns_names(ut_utils.string_to_table(a_exclude_xpath,'|')); - l_col_info_tab := get_columns_info(a_column_info); - l_xmltable_stmt := generate_xmltab_stmt(l_col_info_tab, l_xpath_inc_tab, l_xpath_exc_tab); + + --Check include and exclude columns and create an actual column list that have to be compared. + --TODO :Reformat + if a_include_xpath is null and a_exclude_xpath is null then + l_act_col_tab := get_columns_info(a_column_info); + elsif a_include_xpath is not null and a_exclude_xpath is null then + l_act_col_tab := get_columns_names(ut_utils.string_to_table(a_include_xpath,'|')); + elsif a_include_xpath is null and a_exclude_xpath is not null then + l_act_col_tab := get_columns_info(a_column_info) multiset except get_columns_names(ut_utils.string_to_table(a_exclude_xpath,'|')); + elsif a_include_xpath is not null and a_exclude_xpath is not null then + l_act_col_tab := get_columns_names(ut_utils.string_to_table(a_include_xpath,'|')) multiset except get_columns_names(ut_utils.string_to_table(a_exclude_xpath,'|')); + end if; + + l_pk_xpath_tabs := get_columns_names(ut_utils.string_to_table(a_join_by_xpath,'|')); + + l_xmltable_stmt := generate_xmltab_stmt(l_act_col_tab); l_temp_string := q'[with exp as (select ucd.*,x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :self_guid) x,]' ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]'; @@ -872,27 +884,26 @@ create or replace package body ut_compound_data_helper is if a_join_by_xpath is null then -- If no key defined do the join on all columns - l_temp_string := q'[select xmlelement( name "ROW", a.item_data) act_item_data, a.data_id act_data_id, xmlelement( name "ROW", e.item_data) exp_item_data, e.data_id exp_data_id, rownum item_no ]' + l_temp_string := q'[ select a.item_data as act_item_data, a.data_id act_data_id, e.item_data as exp_item_data, e.data_id exp_data_id, rownum item_no ]' || q'[from act a full outer join exp e on ( ]'; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql,ut_compound_data_helper.generate_equal_sql(l_col_info_tab, l_xpath_inc_tab, l_xpath_exc_tab)||q'[ ) where a.data_id is null or e.data_id is null]'); + ut_utils.append_to_clob(l_compare_sql,ut_compound_data_helper.generate_equal_sql(l_act_col_tab)||q'[ ) where a.data_id is null or e.data_id is null]'); else -- If key defined do the join or these and where on diffrences - l_temp_string := 'select a.item_data act_item_data, a.data_id act_data_id,' - ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no from act a full outer join exp e on ( '; + l_temp_string := q'[ select a.item_data act_item_data, a.data_id act_data_id,]' + ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no from act a full outer join exp e on ( '; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql,ut_compound_data_helper.generate_join_by_on_stmt (l_pk_xpath_tabs)||' ) where '); + ut_utils.append_to_clob(l_compare_sql,ut_compound_data_helper.generate_join_by_on_stmt (l_pk_xpath_tabs)||' ) '); - l_where_stmt := ut_compound_data_helper.generate_not_equal_sql(l_col_info_tab, l_pk_xpath_tabs); + l_where_stmt := ut_compound_data_helper.generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); case when l_where_stmt is null then null; else - ut_utils.append_to_clob(l_compare_sql,'( '||l_where_stmt||' ) or ( a.data_id is null or e.data_id is null )'); + ut_utils.append_to_clob(l_compare_sql,' where ( '||l_where_stmt||' ) or ( a.data_id is null or e.data_id is null )'); end case; end if; - return l_compare_sql; end; diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index af8a4f748..9d3741803 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -296,7 +296,7 @@ create or replace type body ut_compound_data_value as if (ut_utils.gc_diff_max_rows > l_sql_rowcount ) then ut_compound_data_helper.insert_diffs_result(l_diff_tab,l_diff_id); end if; - + l_sql_rowcount := l_sql_rowcount + l_diff_tab.count; if (ut_utils.gc_diff_max_rows <= l_sql_rowcount and l_max_rows != ut_utils.gc_bc_fetch_limit ) then From 9843e143b5fbcf8c5e92fd3c696ac692c16b1079 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 8 Nov 2018 17:32:32 +0000 Subject: [PATCH 39/83] Code updates for pure sql --- .../data_values/ut_compound_data_diff_tmp.sql | 8 +- .../data_values/ut_compound_data_helper.pkb | 544 ++++++------------ .../data_values/ut_compound_data_helper.pks | 19 +- .../data_values/ut_compound_data_value.tpb | 93 +-- .../data_values/ut_compound_data_value.tps | 4 +- .../ut_curr_usr_compound_helper.pkb | 29 +- .../ut_curr_usr_compound_helper.pks | 6 +- .../data_values/ut_data_value_refcursor.tpb | 34 +- .../expectations/test_expectations_cursor.pkb | 24 +- 9 files changed, 285 insertions(+), 476 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_diff_tmp.sql b/source/expectations/data_values/ut_compound_data_diff_tmp.sql index c285d78fd..242d6c2fc 100644 --- a/source/expectations/data_values/ut_compound_data_diff_tmp.sql +++ b/source/expectations/data_values/ut_compound_data_diff_tmp.sql @@ -18,13 +18,9 @@ create global temporary table ut_compound_data_diff_tmp( act_item_data xmltype, exp_item_data xmltype, item_no integer, - pk_hash raw(128), - item_hash raw(128), duplicate_no integer, - constraint ut_compound_data_diff_tmp_uk1 unique (diff_id,duplicate_no,item_no,item_hash, pk_hash), + constraint ut_compound_data_diff_tmp_uk1 unique (diff_id,duplicate_no,item_no), constraint ut_compound_data_diff_tmp_chk check( - item_no is not null and pk_hash is null and duplicate_no is null - or item_no is null and item_hash is not null and duplicate_no is not null - or item_no is null and pk_hash is not null and duplicate_no is not null + item_no is not null ) ) on commit preserve rows; diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 6bfe0af6f..99ae439d6 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -24,12 +24,14 @@ create or replace package body ut_compound_data_helper is l_res xmltype; l_data ut_data_value := a_column_details.value; l_key varchar2(4000) := ut_utils.xmlgen_escaped_string(a_column_details.KEY); + l_is_diff number; begin - l_result := '<'||l_key||' xml_valid_name="'||l_key||'">'; + l_result := '<'||l_key||' xml_valid_name="'||l_key; if l_data is of(ut_data_value_xmltype) then - l_result := l_result || (treat(l_data as ut_data_value_xmltype).to_string); + l_result := l_result||'" sql_diffable="0">' || (treat(l_data as ut_data_value_xmltype).to_string); else - l_result := l_result || ut_utils.xmlgen_escaped_string((treat(l_data as ut_data_value_varchar2).data_value)); + l_is_diff := ut_curr_usr_compound_helper.is_sql_compare_int((treat(l_data as ut_data_value_varchar2).data_value)); + l_result := l_result||'" sql_diffable="'||l_is_diff||'">' || ut_utils.xmlgen_escaped_string((treat(l_data as ut_data_value_varchar2).data_value)); end if; l_result := l_result ||''; @@ -208,11 +210,12 @@ create or replace package body ut_compound_data_helper is where dbms_lob.compare(exp.col_val, act.col_val) != 0) unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') ) union all - select item_no as rn, case when exp_data_id is null then 'Extra' else 'Missing' end as diff_type, + select item_no as rn, case when exp_data_id is null then 'Extra:' else 'Missing:' end as diff_type, xmlserialize(content (case when exp_data_id is null then act_item_data else exp_item_data end) no indent) diffed_row, nvl2(i.join_by,ut3.ut_compound_data_helper.get_pk_value(i.join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value from diff_info i - where act_data_id is null or exp_data_id is null]' + where act_data_id is null or exp_data_id is null + order by 1 , 2]' bulk collect into l_results using a_exclude_xpath,a_include_xpath, a_exclude_xpath,a_include_xpath, @@ -221,125 +224,6 @@ create or replace package body ut_compound_data_helper is return l_results; end; - function get_rows_diff( - a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, - a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2 - ) return tt_row_diffs is - l_column_filter varchar2(32767); - l_results tt_row_diffs; - begin - l_column_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath); - - /** - * Since its unordered search we cannot select max rows from diffs as we miss some comparision records - * We will restrict output on higher level of select - * NO_MERGE hint was introduced to prevent optimizer from merging views and rewriting query which in some cases - * lead to second value being null depend on execution plan that been chosen - **/ - execute immediate q'[ - with diff_info as (select item_hash,pk_hash,duplicate_no from ut_compound_data_diff_tmp ucdc where diff_id = :diff_guid) - select rn,diff_type,diffed_row,pk_value from - ( - select - diff_type, diffed_row, - dense_rank() over (order by case when diff_type in ('Extra','Missing') then diff_type end, - case when diff_type in ('Actual','Expected') then pk_hash end, - case when diff_type in ('Extra','Missing') then pk_hash end, - case when diff_type in ('Actual','Expected') then diff_type end) rn, - pk_value, pk_hash - from - ( - select diff_type,diffed_row,pk_hash,pk_value from - (select diff_type,data_item diffed_row,pk_hash,pk_value - from - (select /*+NO_MERGE*/ nvl(exp.pk_hash, act.pk_hash) pk_hash,nvl(exp.pk_value, act.pk_value) pk_value, - xmlserialize(content exp.row_data no indent) exp_item, - xmlserialize(content act.row_data no indent) act_item - from - (select ucd.* - from - (select ucd.column_value row_data, - r.item_hash row_hash, - r.pk_hash , - r.duplicate_no, - ucd.column_value.getclobval() col_val, - ucd.column_value.getRootElement() col_name, - ut_compound_data_helper.get_pk_value(:join_xpath,r.item_data) pk_value - from - (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_hash, i.pk_hash, i.duplicate_no - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :self_guid - and ucd.item_hash = i.item_hash - ) r, - table( xmlsequence( extract(r.item_data,'/*/*') ) ) ucd - ) ucd - ) exp - join ( - select ucd.* - from - (select ucd.column_value row_data, - r.item_hash row_hash, - r.pk_hash , - r.duplicate_no, - ucd.column_value.getclobval() col_val, - ucd.column_value.getRootElement() col_name, - ut_compound_data_helper.get_pk_value(:join_xpath,r.item_data) pk_value - from - (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_hash, i.pk_hash, i.duplicate_no - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :other_guid - and ucd.item_hash = i.item_hash - ) r, - table( xmlsequence( extract(r.item_data,'/*/*') ) ) ucd - ) ucd - ) act - on exp.pk_hash = act.pk_hash and exp.col_name = act.col_name - and exp.duplicate_no = act.duplicate_no - where dbms_lob.compare(exp.col_val, act.col_val) != 0 - ) - unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') ) - ) - union all - select case when exp.pk_hash is null then 'Extra' else 'Missing' end as diff_type, - xmlserialize(content nvl(exp.item_data, act.item_data) no indent) diffed_row, - coalesce(exp.pk_hash,act.pk_hash) pk_hash, - coalesce(exp.pk_value,act.pk_value) pk_value - from (select extract(deletexml(ucd.item_data, :join_by),'/*/*') item_data,i.pk_hash, - ut_compound_data_helper.get_pk_value(:join_by,item_data) pk_value - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :self_guid - and ucd.item_hash = i.item_hash - ) exp - full outer join ( - select extract(deletexml(ucd.item_data, :join_by),'/*/*') item_data,i.pk_hash, - ut_compound_data_helper.get_pk_value(:join_by,item_data) pk_value - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :other_guid - and ucd.item_hash = i.item_hash - )act - on exp.pk_hash = act.pk_hash - where exp.pk_hash is null or act.pk_hash is null - ) - ) where rn <= :max_rows - order by rn, pk_hash, diff_type - ]' - bulk collect into l_results - using a_diff_id, - a_join_by_xpath, - a_exclude_xpath, a_include_xpath, a_expected_dataset_guid, - a_join_by_xpath, - a_exclude_xpath, a_include_xpath, a_actual_dataset_guid, - a_join_by_xpath,a_join_by_xpath,a_expected_dataset_guid,a_join_by_xpath,a_join_by_xpath, a_actual_dataset_guid, - a_max_rows; - - return l_results; - end; - function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2 @@ -348,11 +232,12 @@ create or replace package body ut_compound_data_helper is l_results tt_row_diffs; begin l_column_filter := get_columns_filter(a_exclude_xpath,a_include_xpath); + execute immediate q'[ with - diff_info as ( select item_no + diff_info as ( select item_no ,exp_item_data, act_item_data,exp_data_id, act_data_id from - (select item_no from ut_compound_data_diff_tmp ucdc where diff_id = :diff_guid order by item_no asc) + (select item_no,exp_item_data,exp_data_id, act_item_data, act_data_id from ut_compound_data_diff_tmp ucdc where diff_id = :diff_guid order by item_no asc) where rownum <= :max_rows) select * from (select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, null pk_value @@ -361,24 +246,30 @@ create or replace package body ut_compound_data_helper is xmlagg(act.col order by act.col_no) act_item from (select r.item_no as rn, rownum col_no, s.column_value col, s.column_value.getRootElement() col_name, - s.column_value.getclobval() col_val - from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_data item_data_no_filter - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :self_guid - and ucd.item_no = i.item_no + s.column_value.getclobval() col_val, + r.data_id + from ( + select ]'||l_column_filter||q'[, ucd.item_no, ucd.exp_data_id as data_id + from + ( select exp_item_data as item_data, i.item_no, i.exp_data_id + from diff_info i + where i.exp_data_id = :self_guid + ) ucd ) r, table( xmlsequence( extract(r.item_data,'/*/*') ) ) s ) exp - join ( + join ( select item_no as rn, rownum col_no, s.column_value col, s.column_value.getRootElement() col_name, - s.column_value.getclobval() col_val - from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_data item_data_no_filter - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :other_guid - and ucd.item_no = i.item_no + s.column_value.getclobval() col_val, + r.data_id + from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.act_data_id as data_id + from + ( + select act_item_data as item_data, i.item_no,i.act_data_id + from diff_info i + where i.act_data_id = :other_guid + ) ucd ) r, table( xmlsequence( extract(r.item_data,'/*/*') ) ) s ) act @@ -390,22 +281,20 @@ create or replace package body ut_compound_data_helper is ) union all select nvl(exp.item_no, act.item_no) rn, - case when exp.item_no is null then 'Extra:' else 'Missing:' end as diff_type, - xmlserialize(content nvl(exp.item_data, act.item_data) no indent) diffed_row, + case when exp.data_id is null then 'Extra:' else 'Missing:' end as diff_type, + xmlserialize(content (case when exp.data_id is null then act.item_data else exp.item_data end) no indent) diffed_row, null pk_value - from (select ucd.item_no, extract(ucd.item_data,'/*/*') item_data - from ut_compound_data_tmp ucd - where ucd.data_id = :self_guid - and ucd.item_no in (select i.item_no from diff_info i) + from (select ucd.item_no, extract(ucd.exp_item_data,'/*/*') item_data, ucd.exp_data_id data_id + from diff_info ucd + where ucd.exp_data_id = :self_guid ) exp full outer join ( - select ucd.item_no, extract(ucd.item_data,'/*/*') item_data - from ut_compound_data_tmp ucd - where ucd.data_id = :other_guid - and ucd.item_no in (select i.item_no from diff_info i) + select ucd.item_no, extract(ucd.act_item_data,'/*/*') item_data, ucd.act_data_id data_id + from diff_info ucd + where ucd.act_data_id = :other_guid )act on exp.item_no = act.item_no - where exp.item_no is null or act.item_no is null + where exp.data_id is null or act.data_id is null order by 1, 2]' bulk collect into l_results using a_diff_id, a_max_rows, @@ -415,115 +304,17 @@ create or replace package body ut_compound_data_helper is return l_results; end; - function get_rows_diff_unordered( - a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, - a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2 - ) return tt_row_diffs is - l_column_filter varchar2(32767); - l_results tt_row_diffs; - begin - l_column_filter := get_columns_filter(a_exclude_xpath,a_include_xpath); - - /** - * Since its unordered search we cannot select max rows from diffs as we miss some comparision records - * We will restrict output on higher level of select - */ - execute immediate q'[with - diff_info as (select item_hash,duplicate_no from ut_compound_data_diff_tmp ucdc where diff_id = :diff_guid) - select duplicate_no, - diffed_type, - diffed_row, - null pk_value - from - (select - coalesce(exp.duplicate_no,act.duplicate_no) duplicate_no, - case - when act.row_hash is null then - 'Missing:' - else 'Extra:' - end diffed_type, - case when exp.row_hash is null then - xmlserialize(content act.row_data no indent) - when act.row_hash is null then - xmlserialize(content exp.row_data no indent) - end diffed_row - from (select ucd.* - from (select ucd.column_value row_data, - r.item_hash row_hash, - r.duplicate_no - from (select ]'||l_column_filter||q'[, ucd.item_no, i.item_hash, i.duplicate_no - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :self_guid - and ucd.item_hash = i.item_hash - and ucd.duplicate_no = i.duplicate_no - ) r, - table( xmlsequence( extract(r.item_data,'/*') ) ) ucd - ) ucd - ) exp - full outer join - (select ucd.* - from (select ucd.column_value row_data, - r.item_hash row_hash, - r.duplicate_no - from (select ]'||l_column_filter||q'[, ucd.item_no, i.item_hash, i.duplicate_no - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :other_guid - and ucd.item_hash = i.item_hash - and ucd.duplicate_no = i.duplicate_no - ) r, - table( xmlsequence( extract(r.item_data,'/*') ) ) ucd - ) ucd - ) act - on exp.row_hash = act.row_hash - and exp.duplicate_no = act.duplicate_no - where exp.row_hash is null or act.row_hash is null - order by diffed_type, coalesce(exp.row_hash,act.row_hash), duplicate_no - ) - where rownum < :max_rows ]' - bulk collect into l_results - using a_diff_id, - a_exclude_xpath, a_include_xpath, a_expected_dataset_guid, - a_exclude_xpath, a_include_xpath, a_actual_dataset_guid, - a_max_rows; - - return l_results; - - end; - - function compare_type(a_join_by_xpath in varchar2,a_unordered boolean, a_is_sql_diffable integer := 0) return varchar2 is - begin - case - when a_is_sql_diffable = 1 then - return gc_compare_sql; - when a_join_by_xpath is not null then - return gc_compare_join_by; - when a_unordered then - return gc_compare_unordered; - else - return gc_compare_normal; - end case; - end; - function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unorderdered boolean, a_is_sql_diffable integer + a_join_by_xpath varchar2,a_unorderdered boolean ) return tt_row_diffs is - l_result tt_row_diffs := tt_row_diffs(); - l_compare_type varchar2(10):= compare_type(a_join_by_xpath,a_unorderdered, a_is_sql_diffable); + l_result tt_row_diffs := tt_row_diffs(); begin case - when l_compare_type = gc_compare_sql then + when a_unorderdered then l_result := get_rows_diff_by_sql(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, a_max_rows, a_exclude_xpath, a_include_xpath ,a_join_by_xpath); - when l_compare_type = gc_compare_join_by then - l_result := get_rows_diff(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, - a_max_rows, a_exclude_xpath, a_include_xpath ,a_join_by_xpath); - when l_compare_type = gc_compare_unordered then - l_result := get_rows_diff_unordered(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, - a_max_rows, a_exclude_xpath, a_include_xpath); else l_result := get_rows_diff(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, a_max_rows, a_exclude_xpath, a_include_xpath); @@ -600,93 +391,6 @@ create or replace package body ut_compound_data_helper is return l_no_missing_keys; end; - procedure update_row_and_pk_hash(a_self_data_id in raw, a_other_data_id in raw, a_exclude_xpath varchar2, - a_include_xpath varchar2, a_join_by_xpath varchar2) is - l_ut_owner varchar2(250) := ut_utils.ut_owner; - l_column_filter varchar2(32767); - l_pk_hash_sql varchar2(32767); - - function get_column_pk_hash(a_join_by_xpath varchar2) return varchar2 is - l_column varchar2(32767); - begin - /* due to possibility of key being to columns we cannot use xmlextractvalue - usage of xmlagg is possible however it greatly complicates code and performance is impacted. - xpath to be looked at or regex - */ - if a_join_by_xpath is not null then - l_column := l_ut_owner ||'.ut_compound_data_helper.get_hash(extract(ucd.item_data,:join_by_xpath).GetClobVal()) pk_hash'; - else - l_column := ':join_by_xpath pk_hash'; - end if; - return l_column; - end; - - begin - l_column_filter := ut_compound_data_helper.get_columns_filter(a_exclude_xpath, a_include_xpath); - l_pk_hash_sql := get_column_pk_hash(a_join_by_xpath); - - --Use a item hash as pk hash for unordered - execute immediate 'merge into ' || l_ut_owner || '.ut_compound_data_tmp tgt - using ( - select ucd_out.item_hash, - ucd_out.pk_hash, - ucd_out.item_no, - ucd_out.data_id, - row_number() over (partition by ucd_out.pk_hash,ucd_out.item_hash,ucd_out.data_id order by 1,2) duplicate_no - from - ( - select '||l_ut_owner ||'.ut_compound_data_helper.get_hash(ucd.item_data.getclobval()) item_hash, - pk_hash, ucd.item_no, ucd.data_id - from - ( - select '||l_column_filter||','||l_pk_hash_sql||', item_no, data_id - from ' || l_ut_owner || q'[.ut_compound_data_tmp ucd - where data_id = :self_guid or data_id = :other_guid - ) ucd - )ucd_out - ) src - on (tgt.item_no = src.item_no and tgt.data_id = src.data_id) - when matched then update - set tgt.item_hash = src.item_hash, - tgt.pk_hash = src.pk_hash, - tgt.duplicate_no = src.duplicate_no]' - using a_exclude_xpath, a_include_xpath,a_join_by_xpath,a_self_data_id, a_other_data_id; - - end; - - function get_unordered(a_owner in varchar2) return varchar2 is - l_sql varchar2(32767); - begin - l_sql := 'with source_data as - ( select t.data_id,t.item_hash,t.duplicate_no, - pk_hash - from ' || a_owner || '.ut_compound_data_tmp t - where data_id = :self_guid or data_id = :other_guid - ) - select distinct :diff_id,tmp.item_hash,tmp.pk_hash,tmp.duplicate_no - from( - ( - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :self_guid - minus - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :other_guid - ) - union all - ( - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :other_guid - minus - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :self_guid - ))tmp'; - return l_sql; - end; - function get_inclusion_matcher_sql(a_owner in varchar2) return varchar2 is l_sql varchar2(32767); begin @@ -759,18 +463,103 @@ create or replace package body ut_compound_data_helper is l_sql := l_sql || get_inclusion_matcher_sql(a_owner); elsif a_inclusion_matcher and a_negated_match then l_sql := l_sql || get_not_inclusion_matcher_sql(a_owner); - elsif not(a_inclusion_matcher) then - l_sql := l_sql || get_unordered(a_owner); end if; return l_sql; end; - function generate_xmltab_stmt (a_column_info ut_varchar2_list) return clob is + function generate_select_stmt(a_column_info ut_varchar2_list,a_xml_column_info xmltype) return clob is l_sql_stmt clob; + l_col_type varchar2(4000); + l_alias varchar2(10) := 'ucd.'; + l_col_syntax varchar2(4000); + l_ut_owner varchar2(250) := ut_utils.ut_owner; begin - for i in 1..a_column_info.count loop - l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ',' end ||a_column_info(i)||q'[ varchar2(4000) PATH ']'||a_column_info(i)||q'[']'; + for i in (select /*+ CARDINALITY(xt 100) */ + distinct + t.column_value, + xt.is_sql_diff, + xt.type + from + (select a_xml_column_info item_data from dual) x, + xmltable( + '/ROW/*' + passing x.item_data + columns + name varchar2(4000) PATH '@xml_valid_name', + type varchar2(4000) PATH '/', + is_sql_diff varchar2(4000) PATH '@sql_diffable' + ) xt, + table(a_column_info) t + where xt.name = t.column_value) + loop + if i.is_sql_diff = 0 then + l_col_syntax := l_ut_owner ||'.ut_compound_data_helper.get_hash('||l_alias||i.column_value||'.getClobVal()) as '|| i.column_value ; + else + l_col_syntax := l_alias||i.column_value||' as '|| i.column_value ; + end if; + + l_sql_stmt := l_sql_stmt || case + when l_sql_stmt is null then + null + else ',' + end||l_col_syntax; + end loop; + return l_sql_stmt; + end; + + function generate_partition_stmt(a_column_info ut_varchar2_list) return clob is + l_sql_stmt clob; + l_alias varchar2(10) := 'ucd.'; + + begin + for i in 1..a_column_info.count + loop + l_sql_stmt := l_sql_stmt || case + when l_sql_stmt is null then + null + else ',' + end||l_alias||a_column_info(i); + end loop; + l_sql_stmt := 'row_number() over (partition by '|| l_sql_stmt || ' order by '||l_sql_stmt||' ) dup_no '; + return l_sql_stmt; + end; + + function generate_xmltab_stmt (a_column_info ut_varchar2_list,a_xml_column_info xmltype) return clob is + l_sql_stmt clob; + l_col_type varchar2(4000); + begin + for i in (select /*+ CARDINALITY(xt 100) */ + distinct + t.column_value, + xt.is_sql_diff, + xt.type + from + (select a_xml_column_info item_data from dual) x, + xmltable( + '/ROW/*' + passing x.item_data + columns + name varchar2(4000) PATH '@xml_valid_name', + type varchar2(4000) PATH '/', + is_sql_diff varchar2(4000) PATH '@sql_diffable' + ) xt, + table(a_column_info) t + where xt.name = t.column_value) + loop + if i.is_sql_diff = 0 then + l_col_type := 'XMLTYPE'; + elsif i.is_sql_diff = 1 and (i.type IN ('CHAR','VARCHAR2','VARCHAR')) then + l_col_type := 'VARCHAR2(4000)'; + else + l_col_type := i.type; + end if; + + l_sql_stmt := l_sql_stmt || case + when l_sql_stmt is null then + null + else ',' + end ||i.column_value||' '||l_col_type||q'[ PATH ']'||i.column_value||q'[']'; end loop; return l_sql_stmt; end; @@ -822,15 +611,17 @@ create or replace package body ut_compound_data_helper is l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); l_act_col_tab ut_varchar2_list := ut_varchar2_list(); - + l_ut_owner varchar2(250) := ut_utils.ut_owner; l_xmltable_stmt clob; l_where_stmt clob; + l_select_stmt clob; + l_partition_stmt clob; function get_columns_names (a_xpath_tab in ut_varchar2_list) return ut_varchar2_list is l_names_tab ut_varchar2_list := ut_varchar2_list(); begin - select REGEXP_SUBSTR (column_value,'[^(/\*/)](.+)$') + select distinct REGEXP_SUBSTR (column_value,'[^(/\*/)](.+)$') bulk collect into l_names_tab from table(a_xpath_tab); return l_names_tab; @@ -840,7 +631,7 @@ create or replace package body ut_compound_data_helper is l_columns_info ut_varchar2_list := ut_varchar2_list(); begin select /*+ CARDINALITY(xt 100) */ - xt.name + distinct xt.name bulk collect into l_columns_info from (select a_column_info item_data from dual) x, xmltable( @@ -851,7 +642,7 @@ create or replace package body ut_compound_data_helper is ) xt; return l_columns_info; end; - + begin dbms_lob.createtemporary(l_compare_sql, true); @@ -869,51 +660,78 @@ create or replace package body ut_compound_data_helper is l_pk_xpath_tabs := get_columns_names(ut_utils.string_to_table(a_join_by_xpath,'|')); - l_xmltable_stmt := generate_xmltab_stmt(l_act_col_tab); + l_xmltable_stmt := generate_xmltab_stmt(l_act_col_tab,a_column_info); + l_select_stmt := generate_select_stmt(l_act_col_tab,a_column_info); + l_partition_stmt := generate_partition_stmt(l_act_col_tab); + + l_temp_string := 'with exp as ( select ucd.* , '; + ut_utils.append_to_clob(l_compare_sql, l_temp_string); + ut_utils.append_to_clob(l_compare_sql, l_partition_stmt); - l_temp_string := q'[with exp as (select ucd.*,x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :self_guid) x,]' + l_temp_string := 'from (select ucd.item_data, '; + ut_utils.append_to_clob(l_compare_sql, l_temp_string); + ut_utils.append_to_clob(l_compare_sql, l_select_stmt); + + l_temp_string := q'[,x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :self_guid) x,]' ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]'; ut_utils.append_to_clob(l_compare_sql, l_temp_string); ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt); - l_temp_string := q'[ ,item_data xmltype PATH '*' ) ucd),]' - ||q'[act as (select ucd.*, x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :other_guid) x,]' + l_temp_string := q'[ ,item_data xmltype PATH '*' ) ucd ) ucd ) ,]'; + ut_utils.append_to_clob(l_compare_sql,l_temp_string); + + l_temp_string :='act as ( select ucd.* , '; + ut_utils.append_to_clob(l_compare_sql, l_temp_string); + ut_utils.append_to_clob(l_compare_sql, l_partition_stmt); + + l_temp_string := 'from (select ucd.item_data, '; + ut_utils.append_to_clob(l_compare_sql,l_temp_string); + ut_utils.append_to_clob(l_compare_sql, l_select_stmt); + + l_temp_string := q'[, x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :other_guid) x,]' ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' ; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt||q'[ ,item_data xmltype PATH '*') ucd)]'); + ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt||q'[ ,item_data xmltype PATH '*') ucd ) ucd ) ]'); if a_join_by_xpath is null then -- If no key defined do the join on all columns - l_temp_string := q'[ select a.item_data as act_item_data, a.data_id act_data_id, e.item_data as exp_item_data, e.data_id exp_data_id, rownum item_no ]' - || q'[from act a full outer join exp e on ( ]'; + l_temp_string := ' select a.item_data as act_item_data, a.data_id act_data_id,' + ||'e.item_data as exp_item_data, e.data_id exp_data_id, rownum item_no, nvl(e.dup_no,a.dup_no) dup_no ' + ||'from act a full outer join exp e on ( '; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql,ut_compound_data_helper.generate_equal_sql(l_act_col_tab)||q'[ ) where a.data_id is null or e.data_id is null]'); + ut_utils.append_to_clob(l_compare_sql,generate_equal_sql(l_act_col_tab)||q'[ and e.dup_no = a.dup_no ) where a.data_id is null or e.data_id is null]'); else -- If key defined do the join or these and where on diffrences - l_temp_string := q'[ select a.item_data act_item_data, a.data_id act_data_id,]' - ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no from act a full outer join exp e on ( '; + l_temp_string := q'[ select a.item_data act_item_data, a.data_id act_data_id, ]' + ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no,nvl(e.dup_no,a.dup_no) dup_no from act a full outer join exp e on ( e.dup_no = a.dup_no and '; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql,ut_compound_data_helper.generate_join_by_on_stmt (l_pk_xpath_tabs)||' ) '); + ut_utils.append_to_clob(l_compare_sql,generate_join_by_on_stmt (l_pk_xpath_tabs)||' ) '); - l_where_stmt := ut_compound_data_helper.generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); + l_where_stmt := generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); case when l_where_stmt is null then - null; + ut_utils.append_to_clob(l_compare_sql,' where a.data_id is null or e.data_id is null'); else ut_utils.append_to_clob(l_compare_sql,' where ( '||l_where_stmt||' ) or ( a.data_id is null or e.data_id is null )'); end case; end if; - return l_compare_sql; + + --TEST + dbms_output.put_line( l_compare_sql); + return l_compare_sql; end; procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw) is begin forall idx in 1..a_diff_tab.count insert into ut3.ut_compound_data_diff_tmp - ( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no ) + ( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no, duplicate_no ) values - (a_diff_id, xmlelement( name "ROW", a_diff_tab(idx).act_item_data), a_diff_tab(idx).act_data_id,xmlelement( name "ROW", a_diff_tab(idx).exp_item_data), a_diff_tab(idx).exp_data_id,a_diff_tab(idx).item_no); + (a_diff_id, + xmlelement( name "ROW", a_diff_tab(idx).act_item_data), a_diff_tab(idx).act_data_id, + xmlelement( name "ROW", a_diff_tab(idx).exp_item_data), a_diff_tab(idx).exp_data_id, + a_diff_tab(idx).item_no, a_diff_tab(idx).dup_no); end; procedure set_rows_diff(a_rows_diff integer) is diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 7c1933a16..23c6636e8 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -16,10 +16,8 @@ create or replace package ut_compound_data_helper authid definer is limitations under the License. */ - gc_compare_join_by constant varchar2(10):='join_by'; gc_compare_unordered constant varchar2(10):='unordered'; gc_compare_normal constant varchar2(10):='normal'; - gc_compare_sql constant varchar2(10):='sql'; type t_column_diffs is record( diff_type varchar2(1), @@ -54,10 +52,12 @@ create or replace package ut_compound_data_helper authid definer is act_data_id raw(32), exp_item_data xmltype, exp_data_id raw(32), - item_no integer + item_no integer, + dup_no integer ); - type t_diff_tab is table of t_diff_rec; - + + type t_diff_tab is table of t_diff_rec; + function get_column_info_xml(a_column_details ut_key_anyval_pair) return xmltype; function get_columns_filter( @@ -71,13 +71,11 @@ create or replace package ut_compound_data_helper authid definer is function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob; - function compare_type(a_join_by_xpath in varchar2,a_unordered boolean, a_is_sql_diffable integer := 0) return varchar2; - function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unorderdered boolean, a_is_sql_diffable integer - ) return tt_row_diffs; + a_join_by_xpath varchar2,a_unorderdered boolean + ) return tt_row_diffs; subtype t_hash is raw(128); @@ -92,9 +90,6 @@ create or replace package ut_compound_data_helper authid definer is return tt_missing_pk; function get_refcursor_matcher_sql(a_owner in varchar2,a_inclusion_matcher boolean := false, a_negated_match boolean := false) return varchar2; - - procedure update_row_and_pk_hash(a_self_data_id in raw, a_other_data_id in raw, a_exclude_xpath varchar2, - a_include_xpath varchar2, a_join_by_xpath varchar2); function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2) return clob; diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 9d3741803..94c448092 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -89,29 +89,25 @@ create or replace type body ut_compound_data_value as l_row_diffs ut_compound_data_helper.tt_row_diffs; l_compare_type varchar2(10); l_self ut_compound_data_value; - l_is_sql_diff integer := 0; - function get_diff_message (a_row_diff ut_compound_data_helper.t_row_diffs,a_compare_type varchar2) return varchar2 is + function get_diff_message (a_row_diff ut_compound_data_helper.t_row_diffs,a_is_unordered boolean) return varchar2 is begin - if a_compare_type in (ut_compound_data_helper.gc_compare_join_by,ut_compound_data_helper.gc_compare_sql) - and a_row_diff.pk_value is not null then - return ' PK '||a_row_diff.pk_value||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - elsif a_compare_type = ut_compound_data_helper.gc_compare_join_by or a_compare_type = ut_compound_data_helper.gc_compare_normal then + + if a_is_unordered then + if a_row_diff.pk_value is not null then + return ' PK '||a_row_diff.pk_value||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; + else + return rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; + end if; + else return ' Row No. '||a_row_diff.rn||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - elsif a_compare_type in (ut_compound_data_helper.gc_compare_unordered,ut_compound_data_helper.gc_compare_sql) - and a_row_diff.pk_value is null then - return rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - end if; + end if; end; begin if not a_other is of (ut_compound_data_value) then raise value_error; - end if; - - if self is of (ut_data_value_refcursor) then - l_is_sql_diff := treat(self as ut_data_value_refcursor).is_sql_diffable; - end if; + end if; l_actual := treat(a_other as ut_compound_data_value); @@ -122,12 +118,12 @@ create or replace type body ut_compound_data_value as -- First tell how many rows are different - --REDO that is a bit mess ?? - if l_is_sql_diff = 1 then + --TODO: that is a bit mess ?? Can we use global variable for all matchers. + if a_unordered then l_diff_row_count := ut_compound_data_helper.get_rows_diff; else execute immediate 'select count(' - ||case when ( a_join_by_xpath is not null and l_is_sql_diff = 0 ) + ||case when ( a_join_by_xpath is not null ) then 'distinct pk_hash' else '*' end @@ -137,10 +133,9 @@ create or replace type body ut_compound_data_value as end if; if l_diff_row_count > 0 then - l_compare_type := ut_compound_data_helper.compare_type(a_join_by_xpath,a_unordered, l_is_sql_diff); l_row_diffs := ut_compound_data_helper.get_rows_diff( self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, - a_include_xpath, a_join_by_xpath, a_unordered, l_is_sql_diff); + a_include_xpath, a_join_by_xpath, a_unordered); l_message := chr(10) ||'Rows: [ ' || l_diff_row_count ||' differences' || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end @@ -150,7 +145,7 @@ create or replace type body ut_compound_data_value as ut_utils.append_to_clob( l_result, l_message ); for i in 1 .. l_row_diffs.count loop l_results.extend; - l_results(l_results.last) := get_diff_message(l_row_diffs(i),l_compare_type); + l_results(l_results.last) := get_diff_message(l_row_diffs(i),a_unordered); end loop; ut_utils.append_to_clob(l_result,l_results); end if; @@ -164,6 +159,9 @@ create or replace type body ut_compound_data_value as l_column_filter varchar2(32767); l_diff_id ut_compound_data_helper.t_hash; l_result integer; + + l_sql varchar2(32767); + --the XML stylesheet is applied on XML representation of data to exclude column names from comparison --column names and data-types are compared separately --user CHR(38) instead of ampersand to eliminate define request when installing through some IDEs @@ -184,20 +182,40 @@ create or replace type body ut_compound_data_value as if not a_other is of (ut_compound_data_value) then raise value_error; end if; - + l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); l_column_filter := ut_compound_data_helper.get_columns_filter(a_exclude_xpath, a_include_xpath); -- Find differences - execute immediate 'insert into ' || l_ut_owner || '.ut_compound_data_diff_tmp ( diff_id, item_no ) - select :diff_id, nvl(exp.item_no, act.item_no) - from (select '||l_column_filter||', ucd.item_no - from ' || l_ut_owner || '.ut_compound_data_tmp ucd where ucd.data_id = :self_guid) exp + execute immediate 'insert into ' || l_ut_owner || '.ut_compound_data_diff_tmp ( diff_id, item_no,exp_item_data, act_item_data,exp_data_id, act_data_id ) + select :diff_id, nvl(exp.item_no, act.item_no) , exp.item_data, act.item_data, exp.data_id, act.data_id + from ( select '||l_column_filter||', rownum item_no, ucd.data_id + from + (select xmlelement(name "ROW" ,xt.item_data) item_data, t.data_id + from ' || l_ut_owner || q'[.ut_compound_data_tmp t, + xmltable('/ROWSET/ROW' + passing t.item_data + columns + item_data xmltype path '*' + ) xt + where t.data_id = :self_guid) ucd + ) exp full outer join - (select '||l_column_filter||', ucd.item_no - from ' || l_ut_owner || '.ut_compound_data_tmp ucd where ucd.data_id = :l_other_guid) act - on exp.item_no = act.item_no '|| + (select ]'||l_column_filter||', rownum item_no, ucd.data_id + from + ( + select xmlelement(name "ROW" ,xt.item_data) item_data, t.data_id + from ' || l_ut_owner || q'[.ut_compound_data_tmp t, + xmltable('/ROWSET/ROW' + passing t.item_data + columns + item_data xmltype path '*' + ) xt + where t.data_id = :l_other_guid + ) ucd + ) act + on exp.item_no = act.item_no ]'|| 'where nvl( dbms_lob.compare(' || /*the xmltransform removes column names and leaves column data to be compared only*/ ' xmltransform(exp.item_data, :l_xml_data_fmt).getclobval()' || @@ -206,6 +224,7 @@ create or replace type body ut_compound_data_value as ') != 0' using in l_diff_id, a_exclude_xpath, a_include_xpath, self.data_id, a_exclude_xpath, a_include_xpath, l_other.data_id, l_xml_data_fmt, l_xml_data_fmt; + --result is OK only if both are same if sql%rowcount = 0 and self.elements_count = l_other.elements_count then l_result := 0; @@ -234,12 +253,6 @@ create or replace type body ut_compound_data_value as l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - /** - * Due to incompatibility issues in XML between 11 and 12.2 and 12.1 versions we will prepopulate pk_hash upfront to - * avoid optimizer incorrectly rewrite and causing NULL error or ORA-600 - **/ - ut_compound_data_helper.update_row_and_pk_hash(self.data_id, l_other.data_id, a_exclude_xpath,a_include_xpath,a_join_by_xpath); - /*!* * Comparision is based on type of search, for inclusion based search we will look for left join only. * For normal two side diff we will peform minus on two sets two get diffrences. @@ -283,7 +296,7 @@ create or replace type body ut_compound_data_value as l_sql_rowcount integer :=0; begin - + --TODO : Error on xml when same column is more then once in item data xml.Do we need to cleanup ?? l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); @@ -292,7 +305,6 @@ create or replace type body ut_compound_data_value as loop fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; exit when l_diff_tab.count = 0; - --Pass it to helper as authid as definer if (ut_utils.gc_diff_max_rows > l_sql_rowcount ) then ut_compound_data_helper.insert_diffs_result(l_diff_tab,l_diff_id); end if; @@ -303,14 +315,15 @@ create or replace type body ut_compound_data_value as l_max_rows := ut_utils.gc_bc_fetch_limit; end if; end loop; - + ut_compound_data_helper.set_rows_diff(l_sql_rowcount); - --result is OK only if both are same + --result is OK only if both are same if l_sql_rowcount = 0 and self.elements_count = l_other.elements_count then - l_result := 0; + l_result := 0; else l_result := 1; end if; + return l_result; end; diff --git a/source/expectations/data_values/ut_compound_data_value.tps b/source/expectations/data_values/ut_compound_data_value.tps index 97370eea6..e1ff43319 100644 --- a/source/expectations/data_values/ut_compound_data_value.tps +++ b/source/expectations/data_values/ut_compound_data_value.tps @@ -44,8 +44,8 @@ create or replace type ut_compound_data_value force under ut_data_value( overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return clob, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2) return integer, + member function compare_implementation_by_sql(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_compare boolean := false) return integer, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean , a_inclusion_compare boolean := false, a_is_negated boolean := false) return integer, - member function compare_implementation_by_sql(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_compare boolean := false) return integer + a_unordered boolean , a_inclusion_compare boolean := false, a_is_negated boolean := false ) return integer ) not final not instantiable / diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb index de8aa6614..5c18c6743 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb @@ -6,7 +6,7 @@ create or replace package body ut_curr_usr_compound_helper is g_anytype_collection_name t_type_name_map; g_user_defined_type pls_integer := dbms_sql.user_defined_type; g_is_collection boolean := false; - g_is_sql_diffable boolean := false; + g_is_sql_diffable boolean := true; procedure set_collection_state(a_is_collection boolean) is begin @@ -18,8 +18,8 @@ create or replace package body ut_curr_usr_compound_helper is procedure set_sql_diff_state(a_is_sql_diff boolean) is begin - --Make sure that we set a g_is_collection only once so we dont reset from true to false. - if not g_is_sql_diffable then + --Make sure that we set a g_is_collection only once so we dont reset from false to true. + if g_is_sql_diffable then g_is_sql_diffable := a_is_sql_diff; end if; end; @@ -27,17 +27,25 @@ create or replace package body ut_curr_usr_compound_helper is function is_sql_compare_allowed(a_type_name varchar2) return boolean is begin --clob/blob/xmltype/object/nestedcursor/nestedtable - if a_type_name IN (g_anytype_name_map(dbms_types.typecode_blob), - g_anytype_name_map(dbms_types.typecode_clob), - g_anytype_name_map(dbms_types.typecode_bfile), - g_anytype_name_map(dbms_types.typecode_varray)) - then + + + if a_type_name IN (g_type_name_map(dbms_sql.blob_type), + g_type_name_map(dbms_sql.clob_type), + g_type_name_map(dbms_sql.bfile_type), + g_type_name_map(dbms_sql.user_defined_type)) + then return false; else return true; end if; end; + function is_sql_compare_int(a_type_name varchar2) return integer is + begin + --raise_application_error(-20111,'no '||a_type_name||ut_utils.boolean_to_int(is_sql_compare_allowed(a_type_name))); + return ut_utils.boolean_to_int(is_sql_compare_allowed(a_type_name)); + end; + function get_column_type(a_desc_rec dbms_sql.desc_rec3, a_desc_user_types boolean := false) return ut_key_anyval_pair is l_data ut_data_value; l_result ut_key_anyval_pair; @@ -54,7 +62,7 @@ create or replace package body ut_curr_usr_compound_helper is return l_typecode = 'COLLECTION'; end; - begin + begin if g_type_name_map.exists(a_desc_rec.col_type) then l_data := ut_data_value_varchar2(g_type_name_map(a_desc_rec.col_type)); set_sql_diff_state(is_sql_compare_allowed(g_type_name_map(a_desc_rec.col_type))); @@ -76,7 +84,7 @@ create or replace package body ut_curr_usr_compound_helper is l_data := ut_data_value_varchar2(a_desc_rec.col_schema_name||'.'||a_desc_rec.col_type_name); set_sql_diff_state(false); end if; - + return ut_key_anyval_pair(a_desc_rec.col_name,l_data); end; @@ -281,6 +289,7 @@ create or replace package body ut_curr_usr_compound_helper is g_type_name_map( dbms_sql.number_type ) := 'NUMBER'; g_type_name_map( dbms_sql.rowid_type ) := 'ROWID'; g_type_name_map( dbms_sql.urowid_type ) := 'UROWID'; + g_type_name_map( dbms_sql.user_defined_type ) := 'USER_DEFINED_TYPE'; end; / diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pks b/source/expectations/data_values/ut_curr_usr_compound_helper.pks index 039b8bfe9..396c5d3b6 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pks +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pks @@ -1,5 +1,9 @@ create or replace package ut_curr_usr_compound_helper authid current_user is + function is_sql_compare_allowed(a_type_name varchar2) return boolean; + + function is_sql_compare_int(a_type_name varchar2) return integer; + procedure get_columns_info( a_cursor in out nocopy sys_refcursor, a_columns_info out nocopy xmltype, @@ -9,6 +13,6 @@ create or replace package ut_curr_usr_compound_helper authid current_user is ); function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return xmltype; - + end; / diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index e253abfc6..6cf8c27b4 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -61,9 +61,8 @@ create or replace type body ut_data_value_refcursor as l_ctx := dbms_xmlgen.newContext(l_cursor); dbms_xmlgen.setNullHandling(l_ctx, dbms_xmlgen.empty_tag); dbms_xmlgen.setMaxRows(l_ctx, c_bulk_rows); - - if self.is_sql_diffable = 1 then - loop + + loop l_xml := dbms_xmlgen.getxmltype(l_ctx); exit when dbms_xmlgen.getNumRowsProcessed(l_ctx) = 0; @@ -74,23 +73,8 @@ create or replace type body ut_data_value_refcursor as using in self.data_id, l_set_id, l_xml; l_set_id := l_set_id + 1; - end loop; - else - loop - l_xml := dbms_xmlgen.getxmltype(l_ctx); - execute immediate - 'insert into ' || l_ut_owner || '.ut_compound_data_tmp(data_id, item_no, item_data) ' || - 'select :self_guid, :self_row_count + rownum, value(a) ' || - ' from table( xmlsequence( extract(:l_xml,''ROWSET/*'') ) ) a' - using in self.data_id, self.elements_count, l_xml; - - exit when sql%rowcount = 0; - - self.elements_count := self.elements_count + sql%rowcount; - end loop; + end loop; - end if; - ut_expectation_processor.reset_nls_params(); if l_cursor%isopen then close l_cursor; @@ -265,17 +249,11 @@ create or replace type body ut_data_value_refcursor as then l_result := 1; end if; - + + if a_unordered then - if self.is_sql_diffable = 1 then - --TODO: :Treat unorder as pk by on all rows - l_result := l_result + (self as ut_compound_data_value).compare_implementation_by_sql(a_other, a_exclude_xpath, a_include_xpath, + l_result := l_result + (self as ut_compound_data_value).compare_implementation_by_sql(a_other, a_exclude_xpath, a_include_xpath, a_join_by_xpath, a_inclusion_compare); - else - --We will make a decision about type of data inside whether we dump into table or do normal row by row - l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, - a_join_by_xpath, a_unordered, a_inclusion_compare); - end if; else l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath); end if; diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 00236f99e..7ac4e0843 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -1087,10 +1087,8 @@ Rows: [ 2 differences ]% l_expected SYS_REFCURSOR; begin --Arrange - open l_actual for select object_id, owner, object_name,object_type from all_objects where owner = user - order by 1,2,3 asc; - open l_expected for select object_id, owner, object_name,object_type from all_objects where owner = user - order by 1,2,3 desc; + open l_actual for select object_id, owner, object_name,object_type from all_objects where owner = user; + open l_expected for select object_id, owner, object_name,object_type from all_objects where owner = user; --Act ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OBJECT_ID'); @@ -1103,13 +1101,11 @@ Rows: [ 2 differences ]% l_expected SYS_REFCURSOR; begin --Arrange - open l_actual for select owner, object_name,object_type from all_objects where owner = user - order by 1,2,3 asc; - open l_expected for select owner, object_name,object_type from all_objects where owner = user - order by 1,2,3 desc; + open l_actual for select object_id, owner, object_name,object_type from all_objects where owner = user; + open l_expected for select object_id, owner, object_name,object_type from all_objects where owner = user; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).join_by(ut3.ut_varchar2_list('OBJECT_NAME,OBJECT_TYPE')); + ut3.ut.expect(l_actual).to_equal(l_expected).join_by(ut3.ut_varchar2_list('OBJECT_ID,OBJECT_NAME')); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; @@ -1310,8 +1306,8 @@ Diff:% l_expected_message := q'[%Actual: refcursor [ count = % ] was expected to equal: refcursor [ count = % ] %Diff:% %Rows: [ 2 differences ]% -%PK TEST-610 - Extra% -%PK TEST-600 - Missing%]'; +%PK TEST-610 - Extra: TEST-610% +%PK TEST-600 - Missing: TEST-600%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -1366,7 +1362,7 @@ Diff:% open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 4; open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('SOME_COL'); + ut3.ut.expect(l_actual).to_equal(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('RN'); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; @@ -1380,7 +1376,7 @@ Diff:% open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 4; open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('SOME_COL'); + ut3.ut.expect(l_actual).to_equal(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('RN'); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; @@ -1726,7 +1722,7 @@ Diff:% --Assert l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ]% %Diff:% -%Rows: [ 2 differences ]% +%Rows: [ 4 differences ]% %PK %%%%%%%%%%%%%Extra%%% %PK %%%%%%%%%%%%%Extra%%% %PK %%%%%%%%%%%%%Missing%%% From ab593d97bd34b5399fd5d8f4c8f73dc13dadf1d4 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Fri, 9 Nov 2018 22:19:31 +0000 Subject: [PATCH 40/83] Update code to consolidate compare sqls into one place where is generated dynamically --- .../data_values/ut_compound_data_helper.pkb | 184 +++++++----------- .../data_values/ut_compound_data_helper.pks | 6 +- .../data_values/ut_compound_data_value.tpb | 64 +----- .../data_values/ut_compound_data_value.tps | 5 +- .../ut_curr_usr_compound_helper.pkb | 68 +++---- .../ut_curr_usr_compound_helper.pks | 7 +- .../data_values/ut_data_value_refcursor.tpb | 6 +- .../data_values/ut_data_value_refcursor.tps | 6 - .../expectations/test_expectations_cursor.pkb | 4 +- 9 files changed, 122 insertions(+), 228 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 99ae439d6..d1c36b1d0 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -25,16 +25,15 @@ create or replace package body ut_compound_data_helper is l_data ut_data_value := a_column_details.value; l_key varchar2(4000) := ut_utils.xmlgen_escaped_string(a_column_details.KEY); l_is_diff number; - begin + begin l_result := '<'||l_key||' xml_valid_name="'||l_key; if l_data is of(ut_data_value_xmltype) then - l_result := l_result||'" sql_diffable="0">' || (treat(l_data as ut_data_value_xmltype).to_string); + l_result := l_result||'" sql_diffable="0" user_defined="1" >' ||trim( both '''' from (treat(l_data as ut_data_value_xmltype).to_string)); else l_is_diff := ut_curr_usr_compound_helper.is_sql_compare_int((treat(l_data as ut_data_value_varchar2).data_value)); - l_result := l_result||'" sql_diffable="'||l_is_diff||'">' || ut_utils.xmlgen_escaped_string((treat(l_data as ut_data_value_varchar2).data_value)); + l_result := l_result||'" sql_diffable="'||l_is_diff||'" user_defined="0">' || ut_utils.xmlgen_escaped_string((treat(l_data as ut_data_value_varchar2).data_value)); end if; - - l_result := l_result ||''; + l_result := l_result ||''; return xmltype(l_result); end; @@ -202,6 +201,8 @@ create or replace package body ut_compound_data_helper is from diff_info i, table( xmlsequence( extract(i.act_item_data,'/*/*') ) ) s where i.act_data_id = :other_guid) + select rn, diff_type, diffed_row, pk_value pk_value + from ( select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value from ( select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item @@ -215,7 +216,8 @@ create or replace package body ut_compound_data_helper is nvl2(i.join_by,ut3.ut_compound_data_helper.get_pk_value(i.join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value from diff_info i where act_data_id is null or exp_data_id is null - order by 1 , 2]' + ) + order by 2, 1]' bulk collect into l_results using a_exclude_xpath,a_include_xpath, a_exclude_xpath,a_include_xpath, @@ -359,7 +361,7 @@ create or replace package body ut_compound_data_helper is if a_join_by_xpath is not null then l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); l_column_filter := get_columns_row_filter(a_exclude_xpath, a_include_xpath); - + execute immediate q'[ with xpaths_tab as (select column_value xpath from table(:xpath_tabs)), expected_column_info as ( select :expected as item_data from dual ), @@ -390,84 +392,7 @@ create or replace package body ut_compound_data_helper is return l_no_missing_keys; end; - - function get_inclusion_matcher_sql(a_owner in varchar2) return varchar2 is - l_sql varchar2(32767); - begin - l_sql := 'with source_data as - ( select t.data_id,t.item_hash,t.duplicate_no, - pk_hash - from ' || a_owner || '.ut_compound_data_tmp t - where data_id = :self_guid or data_id = :other_guid - ) - select distinct :diff_id,tmp.item_hash,tmp.pk_hash,tmp.duplicate_no - from( - ( - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :self_guid - minus - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t - where t.data_id = :other_guid - ) - union all - ( - select t.item_hash,t. duplicate_no,t.pk_hash - from source_data t, - source_data s - where t.data_id = :other_guid - and s.data_id = :self_guid - and t.pk_hash = s.pk_hash - and t.item_hash != s.item_hash - ) - ) - tmp'; - return l_sql; - end; - - function get_not_inclusion_matcher_sql(a_owner in varchar2) return varchar2 is - l_sql varchar2(32767); - begin - /* Self set does not contain any values from other set */ - l_sql := 'with source_data as - ( select t.data_id,t.item_hash,t.duplicate_no, - pk_hash - from ' || a_owner || '.ut_compound_data_tmp t - where data_id = :self_guid or data_id = :other_guid - ) - select distinct :diff_id,tmp.item_hash,tmp.pk_hash,tmp.duplicate_no - from - ( - select act.item_hash,act. duplicate_no,act.pk_hash - from source_data act where act.data_id = :self_guid - and exists ( select 1 - from source_data exp - where exp.data_id = :other_guid - and exp.item_hash = act.item_hash - ) - union all - select null,null,null - from dual where :other_guid = :self_guid - ) - tmp'; - return l_sql; - end; - - -- TODO:Rebuild as the unordered can be done using join_by compare - function get_refcursor_matcher_sql(a_owner in varchar2,a_inclusion_matcher boolean := false, a_negated_match boolean := false) return varchar2 is - l_sql varchar2(32767); - begin - l_sql := 'insert into ' || a_owner || '.ut_compound_data_diff_tmp ( diff_id,item_hash,pk_hash,duplicate_no)'||chr(10); - if a_inclusion_matcher and not(a_negated_match) then - l_sql := l_sql || get_inclusion_matcher_sql(a_owner); - elsif a_inclusion_matcher and a_negated_match then - l_sql := l_sql || get_not_inclusion_matcher_sql(a_owner); - end if; - - return l_sql; - end; - + function generate_select_stmt(a_column_info ut_varchar2_list,a_xml_column_info xmltype) return clob is l_sql_stmt clob; l_col_type varchar2(4000); @@ -570,19 +495,41 @@ create or replace package body ut_compound_data_helper is for i in 1..a_column_info.count loop l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||a_column_info(i)||q'[ = ]'||' e.'||a_column_info(i); end loop; - return l_sql_stmt; end; - function generate_join_by_on_stmt (a_join_by_xpath_tab ut_varchar2_list) return clob is + function generate_join_by_on_stmt (a_join_by_xpath_tab ut_varchar2_list, a_columns_info xmltype, a_join_by_xpath in varchar2) return clob is l_sql_stmt clob; - begin - for i in (with xpaths_tab as (select column_value xpath from table(a_join_by_xpath_tab)) - select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$') name - from xpaths_tab) + l_non_diff_var varchar2(32767); + l_ut_owner varchar2(250) := ut_utils.ut_owner; + begin + for i in (select /*+ CARDINALITY(xt 100) */ + distinct + t.column_value, + xt.is_sql_diff + from + (select a_columns_info item_data from dual) x, + xmltable( + '/ROW/*' + passing x.item_data + columns + name varchar2(4000) PATH '@xml_valid_name', + is_sql_diff varchar2(4000) PATH '@sql_diffable' + ) xt, + table(a_join_by_xpath_tab) t + where xt.name = t.column_value) loop - l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.name||q'[ = ]'||' e.'||i.name; + + if i.is_sql_diff = 0 then + l_non_diff_var := l_ut_owner ||'.ut_compound_data_helper.get_hash((extract( a.'||i.column_value||','||a_join_by_xpath||')).getclobval()) = ' + ||l_ut_owner ||'.ut_compound_data_helper.get_hash((extract( e.'||i.column_value||','||a_join_by_xpath||')).getclobval())'; + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.column_value||q'[ = ]'||' e.'||i.column_value; + elsif i.is_sql_diff = 1 then + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.column_value||q'[ = ]'||' e.'||i.column_value; + end if; + end loop; + return l_sql_stmt; end; @@ -605,7 +552,7 @@ create or replace package body ut_compound_data_helper is end; function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, - a_include_xpath varchar2, a_join_by_xpath varchar2) return clob is + a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean ) return clob is l_compare_sql clob; l_temp_string varchar2(32767); @@ -621,7 +568,7 @@ create or replace package body ut_compound_data_helper is function get_columns_names (a_xpath_tab in ut_varchar2_list) return ut_varchar2_list is l_names_tab ut_varchar2_list := ut_varchar2_list(); begin - select distinct REGEXP_SUBSTR (column_value,'[^(/\*/)](.+)$') + select distinct REGEXP_SUBSTR (column_value,'[^(\/*\/)]+',1,1) bulk collect into l_names_tab from table(a_xpath_tab); return l_names_tab; @@ -642,12 +589,23 @@ create or replace package body ut_compound_data_helper is ) xt; return l_columns_info; end; - + + function get_join_type(a_inclusion_compare in boolean,a_negated in boolean) return varchar2 is + begin + if a_inclusion_compare and not(a_negated) then + return ' right outer join '; + elsif a_inclusion_compare and a_negated then + return ' inner join '; + else + return ' full outer join '; + end if; + end; + begin dbms_lob.createtemporary(l_compare_sql, true); + --TODO: Resolve issues with collection and nested tables, can we extract by internal column name if defined e.g. xml of colval.id.getclobval() --Check include and exclude columns and create an actual column list that have to be compared. - --TODO :Reformat if a_include_xpath is null and a_exclude_xpath is null then l_act_col_tab := get_columns_info(a_column_info); elsif a_include_xpath is not null and a_exclude_xpath is null then @@ -697,28 +655,34 @@ create or replace package body ut_compound_data_helper is -- If no key defined do the join on all columns l_temp_string := ' select a.item_data as act_item_data, a.data_id act_data_id,' ||'e.item_data as exp_item_data, e.data_id exp_data_id, rownum item_no, nvl(e.dup_no,a.dup_no) dup_no ' - ||'from act a full outer join exp e on ( '; + ||'from act a '||get_join_type(a_inclusion_type,a_is_negated)||' exp e on ( '; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql,generate_equal_sql(l_act_col_tab)||q'[ and e.dup_no = a.dup_no ) where a.data_id is null or e.data_id is null]'); + ut_utils.append_to_clob(l_compare_sql,generate_equal_sql(l_act_col_tab)||q'[ and e.dup_no = a.dup_no ) where ]'); else -- If key defined do the join or these and where on diffrences l_temp_string := q'[ select a.item_data act_item_data, a.data_id act_data_id, ]' - ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no,nvl(e.dup_no,a.dup_no) dup_no from act a full outer join exp e on ( e.dup_no = a.dup_no and '; + ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no,nvl(e.dup_no,a.dup_no) dup_no from act a '||get_join_type(a_inclusion_type,a_is_negated)||' exp e on ( e.dup_no = a.dup_no and '; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql,generate_join_by_on_stmt (l_pk_xpath_tabs)||' ) '); + ut_utils.append_to_clob(l_compare_sql,generate_join_by_on_stmt (l_pk_xpath_tabs,a_column_info,a_join_by_xpath)||' ) where'); - l_where_stmt := generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); - case - when l_where_stmt is null then - ut_utils.append_to_clob(l_compare_sql,' where a.data_id is null or e.data_id is null'); - else - ut_utils.append_to_clob(l_compare_sql,' where ( '||l_where_stmt||' ) or ( a.data_id is null or e.data_id is null )'); - end case; + + if not a_is_negated then + l_where_stmt := generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); + if l_where_stmt is not null then + ut_utils.append_to_clob(l_compare_sql,' ( '||l_where_stmt||' ) or '); + end if; + end if; end if; - - --TEST - dbms_output.put_line( l_compare_sql); + + --If its inlcusion we expect a actual set to fully match and have no extra elements over expected + if a_inclusion_type and not(a_is_negated) then + l_temp_string := ' ( a.data_id is null ) '; + else + l_temp_string := ' (a.data_id is null or e.data_id is null) '; + end if; + ut_utils.append_to_clob(l_compare_sql,l_temp_string); + return l_compare_sql; end; diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 23c6636e8..5c72edf90 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -88,11 +88,9 @@ create or replace package ut_compound_data_helper authid definer is function is_pk_exists(a_expected_cursor xmltype, a_actual_cursor xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2,a_join_by_xpath varchar2) return tt_missing_pk; - - function get_refcursor_matcher_sql(a_owner in varchar2,a_inclusion_matcher boolean := false, a_negated_match boolean := false) return varchar2; - + function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, - a_include_xpath varchar2, a_join_by_xpath varchar2) return clob; + a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean ) return clob; procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw); diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 94c448092..f48aec888 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -234,58 +234,10 @@ create or replace type body ut_compound_data_value as return l_result; end; - member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean , a_inclusion_compare boolean := false, a_is_negated boolean := false ) return integer is - l_other ut_compound_data_value; - l_ut_owner varchar2(250) := ut_utils.ut_owner; - l_diff_id ut_compound_data_helper.t_hash; - l_result integer; - l_row_diffs ut_compound_data_helper.tt_row_diffs; - c_max_rows constant integer := 20; - l_sql varchar2(32767); - - begin - if not a_other is of (ut_compound_data_value) then - raise value_error; - end if; - - l_other := treat(a_other as ut_compound_data_value); - - l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - - /*!* - * Comparision is based on type of search, for inclusion based search we will look for left join only. - * For normal two side diff we will peform minus on two sets two get diffrences. - * SELF is expected. - * Due to growing complexity I have moved a dynamic SQL into helper package. - */ - l_sql := ut_compound_data_helper.get_refcursor_matcher_sql(l_ut_owner,a_inclusion_compare,a_is_negated); + member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_join_by_xpath varchar2,a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false ) return integer is - execute immediate l_sql - using self.data_id, l_other.data_id, - l_diff_id, - self.data_id, l_other.data_id, - l_other.data_id,self.data_id; - - /*!* - * Result OK when is not inclusion matcher and both are the same - * Resullt OK when is inclusion matcher and left contains right set - */ - if sql%rowcount = 0 and self.elements_count = l_other.elements_count and not(a_inclusion_compare ) then - l_result := 0; - elsif sql%rowcount = 0 and a_inclusion_compare then - l_result := 0; - else - l_result := 1; - end if; - return l_result; - end; - - member function compare_implementation_by_sql(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_compare boolean := false) return integer is - - l_actual ut_data_value_refcursor := treat(a_other as ut_data_value_refcursor); - l_diff_id ut_compound_data_helper.t_hash; - + l_diff_id ut_compound_data_helper.t_hash; l_other ut_compound_data_value; l_result integer; --We will start with number od differences being displayed. @@ -299,16 +251,16 @@ create or replace type body ut_compound_data_value as --TODO : Error on xml when same column is more then once in item data xml.Do we need to cleanup ?? l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - - open l_loop_curs for ut_compound_data_helper.gen_compare_sql(l_actual.columns_info, a_exclude_xpath, - a_include_xpath, a_join_by_xpath) using self.data_id,l_actual.data_id; + + open l_loop_curs for ut_compound_data_helper.gen_compare_sql(treat(a_other as ut_data_value_refcursor).columns_info, a_exclude_xpath, + a_include_xpath, a_join_by_xpath, a_inclusion_compare, a_is_negated) using self.data_id,l_other.data_id; loop fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; exit when l_diff_tab.count = 0; if (ut_utils.gc_diff_max_rows > l_sql_rowcount ) then ut_compound_data_helper.insert_diffs_result(l_diff_tab,l_diff_id); end if; - + l_sql_rowcount := l_sql_rowcount + l_diff_tab.count; if (ut_utils.gc_diff_max_rows <= l_sql_rowcount and l_max_rows != ut_utils.gc_bc_fetch_limit ) then @@ -318,7 +270,7 @@ create or replace type body ut_compound_data_value as ut_compound_data_helper.set_rows_diff(l_sql_rowcount); --result is OK only if both are same - if l_sql_rowcount = 0 and self.elements_count = l_other.elements_count then + if l_sql_rowcount = 0 and ( self.elements_count = l_other.elements_count or a_inclusion_compare )then l_result := 0; else l_result := 1; diff --git a/source/expectations/data_values/ut_compound_data_value.tps b/source/expectations/data_values/ut_compound_data_value.tps index e1ff43319..2e76bb8f8 100644 --- a/source/expectations/data_values/ut_compound_data_value.tps +++ b/source/expectations/data_values/ut_compound_data_value.tps @@ -44,8 +44,7 @@ create or replace type ut_compound_data_value force under ut_data_value( overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return clob, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2) return integer, - member function compare_implementation_by_sql(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_compare boolean := false) return integer, - member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean , a_inclusion_compare boolean := false, a_is_negated boolean := false ) return integer + member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_join_by_xpath varchar2, a_unordered boolean, a_inclusion_compare boolean := false,a_is_negated boolean := false ) return integer ) not final not instantiable / diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb index 5c18c6743..5efd64e9e 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb @@ -6,7 +6,6 @@ create or replace package body ut_curr_usr_compound_helper is g_anytype_collection_name t_type_name_map; g_user_defined_type pls_integer := dbms_sql.user_defined_type; g_is_collection boolean := false; - g_is_sql_diffable boolean := true; procedure set_collection_state(a_is_collection boolean) is begin @@ -16,23 +15,13 @@ create or replace package body ut_curr_usr_compound_helper is end if; end; - procedure set_sql_diff_state(a_is_sql_diff boolean) is - begin - --Make sure that we set a g_is_collection only once so we dont reset from false to true. - if g_is_sql_diffable then - g_is_sql_diffable := a_is_sql_diff; - end if; - end; - function is_sql_compare_allowed(a_type_name varchar2) return boolean is begin --clob/blob/xmltype/object/nestedcursor/nestedtable - if a_type_name IN (g_type_name_map(dbms_sql.blob_type), g_type_name_map(dbms_sql.clob_type), - g_type_name_map(dbms_sql.bfile_type), - g_type_name_map(dbms_sql.user_defined_type)) + g_type_name_map(dbms_sql.bfile_type)) then return false; else @@ -42,7 +31,6 @@ create or replace package body ut_curr_usr_compound_helper is function is_sql_compare_int(a_type_name varchar2) return integer is begin - --raise_application_error(-20111,'no '||a_type_name||ut_utils.boolean_to_int(is_sql_compare_allowed(a_type_name))); return ut_utils.boolean_to_int(is_sql_compare_allowed(a_type_name)); end; @@ -61,32 +49,37 @@ create or replace package body ut_curr_usr_compound_helper is return l_typecode = 'COLLECTION'; end; - + --TODO: Review the types in and resolving begin + if g_type_name_map.exists(a_desc_rec.col_type) then l_data := ut_data_value_varchar2(g_type_name_map(a_desc_rec.col_type)); - set_sql_diff_state(is_sql_compare_allowed(g_type_name_map(a_desc_rec.col_type))); + return ut_key_anyval_pair(a_desc_rec.col_name,l_data); + end if; /*If its a collection regardless is we want to describe user defined types we will return just a name and capture that name */ - elsif a_desc_rec.col_type = g_user_defined_type and is_collection(a_desc_rec.col_schema_name,a_desc_rec.col_type_name) then + + if a_desc_rec.col_type = g_user_defined_type and is_collection(a_desc_rec.col_schema_name,a_desc_rec.col_type_name) then l_data := ut_data_value_varchar2(a_desc_rec.col_schema_name||'.'||a_desc_rec.col_type_name); - set_sql_diff_state(false); set_collection_state(true); - elsif a_desc_rec.col_type = g_user_defined_type and a_desc_user_types then - if a_desc_rec.col_type_name = 'XMLTYPE' - then + return ut_key_anyval_pair(a_desc_rec.col_name,l_data); + end if; + + if a_desc_rec.col_type = g_user_defined_type and a_desc_user_types then + if a_desc_rec.col_type_name = 'XMLTYPE' then l_data := ut_data_value_varchar2(a_desc_rec.col_type_name); else + --This is only time we return xml if its user defined. This is important as its used later. l_data :=ut_data_value_xmltype(get_user_defined_type(a_desc_rec.col_schema_name,a_desc_rec.col_type_name)); end if; - set_sql_diff_state(false); - elsif a_desc_rec.col_schema_name is not null and a_desc_rec.col_type_name is not null then + return ut_key_anyval_pair(a_desc_rec.col_name,l_data); + end if; + + if a_desc_rec.col_schema_name is not null and a_desc_rec.col_type_name is not null then l_data := ut_data_value_varchar2(a_desc_rec.col_schema_name||'.'||a_desc_rec.col_type_name); - set_sql_diff_state(false); + return ut_key_anyval_pair(a_desc_rec.col_name,l_data); end if; - - return ut_key_anyval_pair(a_desc_rec.col_name,l_data); - end; + end; function get_columns_info( a_columns_tab dbms_sql.desc_tab3, a_columns_count integer, a_desc_user_types boolean := false @@ -117,7 +110,7 @@ create or replace package body ut_curr_usr_compound_helper is l_cursor_number := dbms_sql.to_cursor_number( a_cursor ); dbms_sql.describe_columns3( l_cursor_number, l_columns_count, l_columns_desc ); a_cursor := dbms_sql.to_refcursor( l_cursor_number ); - a_columns_tab := get_columns_info( l_columns_desc, l_columns_count, false); + a_columns_tab := get_columns_info( l_columns_desc, l_columns_count, true); a_join_by_tab := get_columns_info( l_columns_desc, l_columns_count, true); end; @@ -125,8 +118,7 @@ create or replace package body ut_curr_usr_compound_helper is a_cursor in out nocopy sys_refcursor, a_columns_info out nocopy xmltype, a_join_by_info out nocopy xmltype, - a_contains_collection out nocopy number, - a_is_sql_diffable out nocopy number + a_contains_collection out nocopy number ) is l_columns_info xmltype; l_join_by_info xmltype; @@ -134,7 +126,7 @@ create or replace package body ut_curr_usr_compound_helper is l_columns_tab ut_key_anyval_pairs; l_join_by_tab ut_key_anyval_pairs; begin - + get_descr_cursor(a_cursor,l_columns_tab,l_join_by_tab); for i in 1..l_columns_tab.COUNT @@ -151,9 +143,8 @@ create or replace package body ut_curr_usr_compound_helper is select XMLELEMENT("ROW",l_columns_info ),XMLELEMENT("ROW",l_join_by_info ) into a_columns_info,a_join_by_info from dual; - + a_contains_collection := ut_utils.boolean_to_int(g_is_collection); - a_is_sql_diffable := ut_utils.boolean_to_int(g_is_sql_diffable); end; function get_anytype_attribute_count (a_anytype anytype) return pls_integer is @@ -215,8 +206,7 @@ create or replace package body ut_curr_usr_compound_helper is end if; end loop; end if; - - + return l_result; end; @@ -235,16 +225,15 @@ create or replace package body ut_curr_usr_compound_helper is l_typecode := l_anydata.gettype(l_anytype); l_columns_tab := get_anytype_attributes_info(l_anytype); - + select xmlagg(xmlelement(evalname key,value)) - into l_result from table(l_columns_tab); - + into l_result from table(l_columns_tab); + return l_result; - end; begin - g_anytype_name_map(dbms_types.typecode_date) :=' DATE'; + g_anytype_name_map(dbms_types.typecode_date) := 'DATE'; g_anytype_name_map(dbms_types.typecode_number) := 'NUMBER'; g_anytype_name_map(dbms_types.typecode_raw) := 'RAW'; g_anytype_name_map(dbms_types.typecode_char) := 'CHAR'; @@ -289,7 +278,6 @@ create or replace package body ut_curr_usr_compound_helper is g_type_name_map( dbms_sql.number_type ) := 'NUMBER'; g_type_name_map( dbms_sql.rowid_type ) := 'ROWID'; g_type_name_map( dbms_sql.urowid_type ) := 'UROWID'; - g_type_name_map( dbms_sql.user_defined_type ) := 'USER_DEFINED_TYPE'; end; / diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pks b/source/expectations/data_values/ut_curr_usr_compound_helper.pks index 396c5d3b6..bbbba0fa3 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pks +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pks @@ -1,15 +1,14 @@ create or replace package ut_curr_usr_compound_helper authid current_user is - + function is_sql_compare_allowed(a_type_name varchar2) return boolean; function is_sql_compare_int(a_type_name varchar2) return integer; - + procedure get_columns_info( a_cursor in out nocopy sys_refcursor, a_columns_info out nocopy xmltype, a_join_by_info out nocopy xmltype, - a_contains_collection out nocopy number, - a_is_sql_diffable out nocopy number + a_contains_collection out nocopy number ); function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return xmltype; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 6cf8c27b4..e73a641f7 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -42,7 +42,7 @@ create or replace type body ut_data_value_refcursor as --Get some more info regarding cursor, including if it containts collection columns and what is their name ut_curr_usr_compound_helper.get_columns_info(l_cursor,self.columns_info,self.key_info, - self.contain_collection,self.is_sql_diffable); + self.contain_collection); self.elements_count := 0; -- We use DBMS_XMLGEN in order to: @@ -252,8 +252,8 @@ create or replace type body ut_data_value_refcursor as if a_unordered then - l_result := l_result + (self as ut_compound_data_value).compare_implementation_by_sql(a_other, a_exclude_xpath, a_include_xpath, - a_join_by_xpath, a_inclusion_compare); + l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, + a_join_by_xpath,a_unordered, a_inclusion_compare, a_is_negated); else l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath); end if; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 5972f710c..36c231887 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -40,12 +40,6 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( */ key_info xmltype, - /** - * Hold info if type contain any of the nonstandard user types which defines way we do compare later. - * Types of clob/blob/xmltype/object/nestedcursor/nestedtable will force into hash - */ - is_sql_diffable number(1,0), - constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) return self as result, member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), overriding member function to_string return varchar2, diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 7ac4e0843..086ad9193 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2342,8 +2342,8 @@ Diff:% l_expected SYS_REFCURSOR; begin --Arrange - open l_actual for select username,user_id from all_users; - open l_expected for select username||'ACT' username ,user_id from all_users where rownum < 5; + open l_actual for select username,rownum * 10 user_id from all_users where rownum < 5; + open l_expected for select username ,rownum user_id from all_users where rownum < 5; --Act ut3.ut.expect(l_actual).not_to_contain(l_expected).join_by('USER_ID'); From 4d3dadcfc8efe3ba0f8d18569cc1f67ce4144ea9 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Fri, 9 Nov 2018 23:37:01 +0000 Subject: [PATCH 41/83] Update for 11g where error about inline with was raised. Update test for min grant user as it produces cartesian --- .../data_values/ut_compound_data_helper.pkb | 63 ++++++++++--------- .../ut_curr_usr_compound_helper.pkb | 4 +- test/min_grant_user/min_grant_user_exp.pkb | 6 +- 3 files changed, 40 insertions(+), 33 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index d1c36b1d0..2a3a095e9 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -17,7 +17,7 @@ create or replace package body ut_compound_data_helper is */ g_user_defined_type pls_integer := dbms_sql.user_defined_type; - gc_diff_count integer; + g_diff_count integer; function get_column_info_xml(a_column_details ut_key_anyval_pair) return xmltype is l_result varchar2(4000); @@ -182,46 +182,53 @@ create or replace package body ut_compound_data_helper is l_act_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','act_item_data'); l_exp_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','exp_item_data'); - execute immediate q'[with diff_info as - ( select act_data_id, exp_data_id,]' - ||l_act_col_filter||','|| l_exp_col_filter||q'[, :join_by join_by, item_no - from ut_compound_data_diff_tmp ucd - where diff_id = :diff_id ), - exp as ( + execute immediate q'[with exp as ( select exp_item_data, exp_data_id, item_no rn,rownum col_no, nvl2(exp_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,exp_item_data),null) pk_value, s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val - from diff_info i, + from ( + select exp_data_id, ]'||l_exp_col_filter||q'[, :join_by join_by, item_no + from ut_compound_data_diff_tmp ucd + where diff_id = :diff_id + and ucd.exp_data_id = :self_guid) i, table( xmlsequence( extract(i.exp_item_data,'/*/*') ) ) s - where i.exp_data_id = :self_guid), + ), act as ( select act_item_data, act_data_id, item_no rn, rownum col_no, nvl2(act_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,act_item_data),null) pk_value, s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val - from diff_info i, + from ( + select act_data_id, ]'||l_act_col_filter||q'[, :join_by join_by, item_no + from ut_compound_data_diff_tmp ucd + where diff_id = :diff_id + and ucd.exp_data_id = :other_guid ) i, table( xmlsequence( extract(i.act_item_data,'/*/*') ) ) s - where i.act_data_id = :other_guid) + ) select rn, diff_type, diffed_row, pk_value pk_value from ( - select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value - from ( - select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item - from exp join act - on exp.rn = act.rn and exp.col_name = act.col_name - where dbms_lob.compare(exp.col_val, act.col_val) != 0) - unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') ) + select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value + from + (select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item + from exp join act on exp.rn = act.rn and exp.col_name = act.col_name + where dbms_lob.compare(exp.col_val, act.col_val) != 0) + unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') + ) union all - select item_no as rn, case when exp_data_id is null then 'Extra:' else 'Missing:' end as diff_type, + select + item_no as rn, case when exp_data_id is null then 'Extra:' else 'Missing:' end as diff_type, xmlserialize(content (case when exp_data_id is null then act_item_data else exp_item_data end) no indent) diffed_row, - nvl2(i.join_by,ut3.ut_compound_data_helper.get_pk_value(i.join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value - from diff_info i - where act_data_id is null or exp_data_id is null + nvl2(:join_by,ut3.ut_compound_data_helper.get_pk_value(:join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value + from ut_compound_data_diff_tmp i + where diff_id = :diff_id + and act_data_id is null or exp_data_id is null ) order by 2, 1]' bulk collect into l_results - using a_exclude_xpath,a_include_xpath, - a_exclude_xpath,a_include_xpath, - a_join_by_xpath, a_diff_id, a_expected_dataset_guid,a_actual_dataset_guid; + using a_exclude_xpath, a_include_xpath, a_join_by_xpath, + a_diff_id, a_expected_dataset_guid, + a_exclude_xpath,a_include_xpath, a_join_by_xpath, + a_diff_id, a_actual_dataset_guid, + a_join_by_xpath,a_join_by_xpath, a_diff_id; return l_results; end; @@ -700,17 +707,17 @@ create or replace package body ut_compound_data_helper is procedure set_rows_diff(a_rows_diff integer) is begin - gc_diff_count := a_rows_diff; + g_diff_count := a_rows_diff; end; procedure cleanup_diff is begin - gc_diff_count := 0; + g_diff_count := 0; end; function get_rows_diff return integer is begin - return gc_diff_count; + return g_diff_count; end; end; diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb index 5efd64e9e..8ea1ab5bb 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb @@ -56,9 +56,9 @@ create or replace package body ut_curr_usr_compound_helper is l_data := ut_data_value_varchar2(g_type_name_map(a_desc_rec.col_type)); return ut_key_anyval_pair(a_desc_rec.col_name,l_data); end if; + /*If its a collection regardless is we want to describe user defined types we will return just a name - and capture that name */ - + and capture that name */ if a_desc_rec.col_type = g_user_defined_type and is_collection(a_desc_rec.col_schema_name,a_desc_rec.col_type_name) then l_data := ut_data_value_varchar2(a_desc_rec.col_schema_name||'.'||a_desc_rec.col_type_name); set_collection_state(true); diff --git a/test/min_grant_user/min_grant_user_exp.pkb b/test/min_grant_user/min_grant_user_exp.pkb index de79219e3..c1600e432 100644 --- a/test/min_grant_user/min_grant_user_exp.pkb +++ b/test/min_grant_user/min_grant_user_exp.pkb @@ -5,13 +5,13 @@ create or replace package body min_grant_user_exp is l_expected SYS_REFCURSOR; begin --Arrange - open l_actual for select owner, object_name,object_type from all_objects where owner = user + open l_actual for select object_id, owner, object_name,object_type from all_objects where owner = user order by 1,2,3 asc; - open l_expected for select owner, object_name,object_type from all_objects where owner = user + open l_expected for select object_id, owner, object_name,object_type from all_objects where owner = user order by 1,2,3 desc; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OWNER'); + ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OBJECT_ID'); end; From d9ccc838eb2c413bdf6b1ec67fafe20851e1ceae Mon Sep 17 00:00:00 2001 From: lwasylow Date: Fri, 9 Nov 2018 23:52:00 +0000 Subject: [PATCH 42/83] Fix to sql diff to resolve 11g optimizer rewrite error --- source/expectations/data_values/ut_compound_data_helper.pkb | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 2a3a095e9..d4d79c4c3 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -178,6 +178,7 @@ create or replace package body ut_compound_data_helper is l_act_col_filter varchar2(32767); l_exp_col_filter varchar2(32767); l_results tt_row_diffs; + begin l_act_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','act_item_data'); l_exp_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','exp_item_data'); @@ -201,7 +202,7 @@ create or replace package body ut_compound_data_helper is select act_data_id, ]'||l_act_col_filter||q'[, :join_by join_by, item_no from ut_compound_data_diff_tmp ucd where diff_id = :diff_id - and ucd.exp_data_id = :other_guid ) i, + and ucd.act_data_id = :other_guid ) i, table( xmlsequence( extract(i.act_item_data,'/*/*') ) ) s ) select rn, diff_type, diffed_row, pk_value pk_value From c009a8608416e5eba468b79a84f4fda702cbba8d Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 10 Nov 2018 20:40:10 +0000 Subject: [PATCH 43/83] Update code to bring all code into one place. Still few issues to resolve. TODO : Nested table, collections and some errors to investigate. TODO : Bring a diffs row into one place. --- .../data_values/ut_compound_data_helper.pkb | 82 ++++++++++++------- .../data_values/ut_compound_data_helper.pks | 7 +- .../data_values/ut_compound_data_value.tpb | 60 +++----------- .../data_values/ut_data_value_refcursor.tpb | 7 +- 4 files changed, 72 insertions(+), 84 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index d4d79c4c3..18a34c6d1 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -183,6 +183,8 @@ create or replace package body ut_compound_data_helper is l_act_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','act_item_data'); l_exp_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','exp_item_data'); + --TODO: Generate a dynamic SQL based on input e.g. no need for PK during unordered and consolidate get_rows_diff + execute immediate q'[with exp as ( select exp_item_data, exp_data_id, item_no rn,rownum col_no, nvl2(exp_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,exp_item_data),null) pk_value, @@ -317,12 +319,12 @@ create or replace package body ut_compound_data_helper is function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unorderdered boolean + a_join_by_xpath varchar2,a_unordered boolean ) return tt_row_diffs is l_result tt_row_diffs := tt_row_diffs(); begin case - when a_unorderdered then + when a_unordered then l_result := get_rows_diff_by_sql(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, a_max_rows, a_exclude_xpath, a_include_xpath ,a_join_by_xpath); else @@ -559,8 +561,9 @@ create or replace package body ut_compound_data_helper is return l_sql_stmt; end; - function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, - a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean ) return clob is + function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean, + a_unordered boolean) return clob is l_compare_sql clob; l_temp_string varchar2(32767); @@ -613,6 +616,7 @@ create or replace package body ut_compound_data_helper is dbms_lob.createtemporary(l_compare_sql, true); --TODO: Resolve issues with collection and nested tables, can we extract by internal column name if defined e.g. xml of colval.id.getclobval() + --TODO: Comment better all pieces --Check include and exclude columns and create an actual column list that have to be compared. if a_include_xpath is null and a_exclude_xpath is null then l_act_col_tab := get_columns_info(a_column_info); @@ -638,12 +642,19 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql, l_temp_string); ut_utils.append_to_clob(l_compare_sql, l_select_stmt); - l_temp_string := q'[,x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :self_guid) x,]' + l_temp_string := ',x.data_id ,' + || case when not a_unordered then 'position ' else 'rownum ' end + ||'item_no from '|| l_ut_owner || '.ut_compound_data_tmp x, ' ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]'; - ut_utils.append_to_clob(l_compare_sql, l_temp_string); + ut_utils.append_to_clob(l_compare_sql, l_temp_string); + + if not a_unordered then + ut_utils.append_to_clob(l_compare_sql,'POSITION for ordinality, '); + end if; + ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt); - l_temp_string := q'[ ,item_data xmltype PATH '*' ) ucd ) ucd ) ,]'; + l_temp_string := q'[ ,item_data xmltype PATH '*' ) ucd where data_id = :self_guid ) ucd ) ,]'; ut_utils.append_to_clob(l_compare_sql,l_temp_string); l_temp_string :='act as ( select ucd.* , '; @@ -654,35 +665,50 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql,l_temp_string); ut_utils.append_to_clob(l_compare_sql, l_select_stmt); - l_temp_string := q'[, x.item_no,x.data_id from (select item_data,item_no,data_id from ]' || l_ut_owner || q'[.ut_compound_data_tmp where data_id = :other_guid) x,]' + l_temp_string := ',x.data_id, ' + || case when not a_unordered then 'position ' else 'rownum ' end + ||'item_no from ' || l_ut_owner || '.ut_compound_data_tmp x,' ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' ; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt||q'[ ,item_data xmltype PATH '*') ucd ) ucd ) ]'); - - if a_join_by_xpath is null then - -- If no key defined do the join on all columns - l_temp_string := ' select a.item_data as act_item_data, a.data_id act_data_id,' - ||'e.item_data as exp_item_data, e.data_id exp_data_id, rownum item_no, nvl(e.dup_no,a.dup_no) dup_no ' + + if not a_unordered then + ut_utils.append_to_clob(l_compare_sql,'POSITION for ordinality, '); + end if; + + ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt||q'[ ,item_data xmltype PATH '*') ucd where data_id = :other_guid ) ucd ) ]'); + + l_temp_string := ' select a.item_data as act_item_data, a.data_id act_data_id,' + ||'e.item_data as exp_item_data, e.data_id exp_data_id, '|| + case when a_unordered then 'rownum item_no' else 'nvl(e.item_no,a.item_no) item_no' end ||', nvl(e.dup_no,a.dup_no) dup_no ' ||'from act a '||get_join_type(a_inclusion_type,a_is_negated)||' exp e on ( '; - ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql,generate_equal_sql(l_act_col_tab)||q'[ and e.dup_no = a.dup_no ) where ]'); - else - -- If key defined do the join or these and where on diffrences - l_temp_string := q'[ select a.item_data act_item_data, a.data_id act_data_id, ]' - ||' e.item_data exp_item_data, e.data_id exp_data_id, rownum item_no,nvl(e.dup_no,a.dup_no) dup_no from act a '||get_join_type(a_inclusion_type,a_is_negated)||' exp e on ( e.dup_no = a.dup_no and '; - ut_utils.append_to_clob(l_compare_sql,l_temp_string); - - ut_utils.append_to_clob(l_compare_sql,generate_join_by_on_stmt (l_pk_xpath_tabs,a_column_info,a_join_by_xpath)||' ) where'); - + ut_utils.append_to_clob(l_compare_sql,l_temp_string); + + if a_unordered then + ut_utils.append_to_clob(l_compare_sql,' e.dup_no = a.dup_no and '); + end if; + + if a_join_by_xpath is null and a_unordered then + -- If no key defined do the join on all columns + ut_utils.append_to_clob(l_compare_sql,generate_equal_sql(l_act_col_tab)); + elsif a_join_by_xpath is not null and a_unordered then + -- If key defined do the join or these and where on diffrences + ut_utils.append_to_clob(l_compare_sql,generate_join_by_on_stmt (l_pk_xpath_tabs,a_column_info,a_join_by_xpath)); + elsif not a_unordered then + ut_utils.append_to_clob(l_compare_sql, 'a.item_no = e.item_no ' ); + end if; - if not a_is_negated then + ut_utils.append_to_clob(l_compare_sql,' ) where '); + + if (a_join_by_xpath is not null) and (a_unordered) and (a_inclusion_type) and (not a_is_negated) then l_where_stmt := generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); if l_where_stmt is not null then ut_utils.append_to_clob(l_compare_sql,' ( '||l_where_stmt||' ) or '); end if; - end if; - end if; - + elsif not a_unordered then + l_where_stmt := generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); + ut_utils.append_to_clob(l_compare_sql,' ( '||l_where_stmt||' ) or '); + end if; + --If its inlcusion we expect a actual set to fully match and have no extra elements over expected if a_inclusion_type and not(a_is_negated) then l_temp_string := ' ( a.data_id is null ) '; diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 5c72edf90..a73fae8dd 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -74,7 +74,7 @@ create or replace package ut_compound_data_helper authid definer is function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unorderdered boolean + a_join_by_xpath varchar2,a_unordered boolean ) return tt_row_diffs; subtype t_hash is raw(128); @@ -89,8 +89,9 @@ create or replace package ut_compound_data_helper authid definer is function is_pk_exists(a_expected_cursor xmltype, a_actual_cursor xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2,a_join_by_xpath varchar2) return tt_missing_pk; - function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, - a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean ) return clob; + function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean, + a_unordered boolean ) return clob; procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw); diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index f48aec888..76a591366 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -119,18 +119,7 @@ create or replace type body ut_compound_data_value as -- First tell how many rows are different --TODO: that is a bit mess ?? Can we use global variable for all matchers. - if a_unordered then - l_diff_row_count := ut_compound_data_helper.get_rows_diff; - else - execute immediate 'select count(' - ||case when ( a_join_by_xpath is not null ) - then 'distinct pk_hash' - else '*' - end - ||') from '|| l_ut_owner || '.ut_compound_data_diff_tmp ' - ||'where diff_id = :diff_id' - into l_diff_row_count using l_diff_id; - end if; + l_diff_row_count := ut_compound_data_helper.get_rows_diff; if l_diff_row_count > 0 then l_row_diffs := ut_compound_data_helper.get_rows_diff( @@ -159,9 +148,6 @@ create or replace type body ut_compound_data_value as l_column_filter varchar2(32767); l_diff_id ut_compound_data_helper.t_hash; l_result integer; - - l_sql varchar2(32767); - --the XML stylesheet is applied on XML representation of data to exclude column names from comparison --column names and data-types are compared separately --user CHR(38) instead of ampersand to eliminate define request when installing through some IDEs @@ -182,40 +168,20 @@ create or replace type body ut_compound_data_value as if not a_other is of (ut_compound_data_value) then raise value_error; end if; - + l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); l_column_filter := ut_compound_data_helper.get_columns_filter(a_exclude_xpath, a_include_xpath); -- Find differences - execute immediate 'insert into ' || l_ut_owner || '.ut_compound_data_diff_tmp ( diff_id, item_no,exp_item_data, act_item_data,exp_data_id, act_data_id ) - select :diff_id, nvl(exp.item_no, act.item_no) , exp.item_data, act.item_data, exp.data_id, act.data_id - from ( select '||l_column_filter||', rownum item_no, ucd.data_id - from - (select xmlelement(name "ROW" ,xt.item_data) item_data, t.data_id - from ' || l_ut_owner || q'[.ut_compound_data_tmp t, - xmltable('/ROWSET/ROW' - passing t.item_data - columns - item_data xmltype path '*' - ) xt - where t.data_id = :self_guid) ucd - ) exp + execute immediate 'insert into ' || l_ut_owner || '.ut_compound_data_diff_tmp ( diff_id, item_no ) + select :diff_id, nvl(exp.item_no, act.item_no) + from (select '||l_column_filter||', ucd.item_no + from ' || l_ut_owner || '.ut_compound_data_tmp ucd where ucd.data_id = :self_guid) exp full outer join - (select ]'||l_column_filter||', rownum item_no, ucd.data_id - from - ( - select xmlelement(name "ROW" ,xt.item_data) item_data, t.data_id - from ' || l_ut_owner || q'[.ut_compound_data_tmp t, - xmltable('/ROWSET/ROW' - passing t.item_data - columns - item_data xmltype path '*' - ) xt - where t.data_id = :l_other_guid - ) ucd - ) act - on exp.item_no = act.item_no ]'|| + (select '||l_column_filter||', ucd.item_no + from ' || l_ut_owner || '.ut_compound_data_tmp ucd where ucd.data_id = :l_other_guid) act + on exp.item_no = act.item_no '|| 'where nvl( dbms_lob.compare(' || /*the xmltransform removes column names and leaves column data to be compared only*/ ' xmltransform(exp.item_data, :l_xml_data_fmt).getclobval()' || @@ -224,11 +190,11 @@ create or replace type body ut_compound_data_value as ') != 0' using in l_diff_id, a_exclude_xpath, a_include_xpath, self.data_id, a_exclude_xpath, a_include_xpath, l_other.data_id, l_xml_data_fmt, l_xml_data_fmt; - --result is OK only if both are same if sql%rowcount = 0 and self.elements_count = l_other.elements_count then l_result := 0; else + ut_compound_data_helper.set_rows_diff(sql%rowcount); l_result := 1; end if; return l_result; @@ -253,7 +219,7 @@ create or replace type body ut_compound_data_value as l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); open l_loop_curs for ut_compound_data_helper.gen_compare_sql(treat(a_other as ut_data_value_refcursor).columns_info, a_exclude_xpath, - a_include_xpath, a_join_by_xpath, a_inclusion_compare, a_is_negated) using self.data_id,l_other.data_id; + a_include_xpath, a_join_by_xpath, a_inclusion_compare, a_is_negated, a_unordered ) using self.data_id,l_other.data_id; loop fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; exit when l_diff_tab.count = 0; @@ -267,12 +233,12 @@ create or replace type body ut_compound_data_value as l_max_rows := ut_utils.gc_bc_fetch_limit; end if; end loop; - - ut_compound_data_helper.set_rows_diff(l_sql_rowcount); + --result is OK only if both are same if l_sql_rowcount = 0 and ( self.elements_count = l_other.elements_count or a_inclusion_compare )then l_result := 0; else + ut_compound_data_helper.set_rows_diff(l_sql_rowcount); l_result := 1; end if; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index e73a641f7..0d93e2abf 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -250,13 +250,8 @@ create or replace type body ut_data_value_refcursor as l_result := 1; end if; - - if a_unordered then - l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, + l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, a_join_by_xpath,a_unordered, a_inclusion_compare, a_is_negated); - else - l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath); - end if; end if; return l_result; From ecaf48a5e632ee5f902e750dd6a136d98ecc1059 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 10 Nov 2018 21:25:16 +0000 Subject: [PATCH 44/83] Add some bigger tests --- .../data_values/ut_compound_data_value.tpb | 1 + .../expectations/test_expectations_cursor.pkb | 28 +++++++++++++++++++ .../expectations/test_expectations_cursor.pks | 6 ++++ 3 files changed, 35 insertions(+) diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 76a591366..cdec16b98 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -215,6 +215,7 @@ create or replace type body ut_compound_data_value as begin --TODO : Error on xml when same column is more then once in item data xml.Do we need to cleanup ?? + --TODO : Bring diffs row into same place for ref data cursor especially (how we going to do that so we dont break anyval etc) l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 086ad9193..1ac1a7485 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -901,6 +901,21 @@ Rows: [ 4 differences ] --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + + procedure compares_over_10000_rows + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + --Arrange + open l_actual for select object_name from all_objects where rownum <=11000; + open l_expected for select object_name from all_objects where rownum <=11000; + --Act + ut3.ut.expect(l_actual).to_equal(l_expected); + + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; function get_cursor return sys_refcursor is l_cursor sys_refcursor; @@ -1261,6 +1276,19 @@ Diff:% ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + procedure cursor_joinby_compare_10000 is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select level object_id, level || '_TEST' object_name from dual connect by level <=11000; + open l_expected for select level object_id, level || '_TEST' object_name from dual connect by level <=11000; + --Act + ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OBJECT_ID'); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + procedure cursor_joinby_compare_fail is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index ca9977f41..42d6f8cab 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -169,6 +169,9 @@ create or replace package test_expectations_cursor is --%test(Compares cursors with more than 1000 rows) procedure compares_over_1000_rows; + --%test(Compares cursors with more than 10000 rows) + procedure compares_over_10000_rows; + --%test(Adds a warning when using depreciated syntax to_equal( a_expected sys_refcursor, a_exclude varchar2 )) procedure deprec_to_equal_excl_varch; @@ -231,6 +234,9 @@ create or replace package test_expectations_cursor is --%test( Compare cursors join by single key more than 1000 rows) procedure cursor_joinby_compare_1000; + + --%test( Compare cursors join by single key more than 10000 rows) + procedure cursor_joinby_compare_10000; --%test( Compare two column cursors join by and fail to match ) procedure cursor_joinby_compare_fail; From af8b49a3685c6f6713d9a9888b0cc309b0f73a33 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 11 Nov 2018 06:40:56 +0000 Subject: [PATCH 45/83] Update rownumber generated --- source/expectations/data_values/ut_compound_data_helper.pkb | 4 ++-- source/expectations/data_values/ut_compound_data_tmp.sql | 4 ++-- source/expectations/data_values/ut_data_value_refcursor.tpb | 6 +++--- 3 files changed, 7 insertions(+), 7 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 18a34c6d1..848dd9ddc 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -643,7 +643,7 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql, l_select_stmt); l_temp_string := ',x.data_id ,' - || case when not a_unordered then 'position ' else 'rownum ' end + || case when not a_unordered then 'position + x.item_no ' else 'rownum ' end ||'item_no from '|| l_ut_owner || '.ut_compound_data_tmp x, ' ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]'; ut_utils.append_to_clob(l_compare_sql, l_temp_string); @@ -666,7 +666,7 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql, l_select_stmt); l_temp_string := ',x.data_id, ' - || case when not a_unordered then 'position ' else 'rownum ' end + || case when not a_unordered then 'position + x.item_no ' else 'rownum ' end ||'item_no from ' || l_ut_owner || '.ut_compound_data_tmp x,' ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' ; ut_utils.append_to_clob(l_compare_sql,l_temp_string); diff --git a/source/expectations/data_values/ut_compound_data_tmp.sql b/source/expectations/data_values/ut_compound_data_tmp.sql index a4c6516af..1d471362f 100644 --- a/source/expectations/data_values/ut_compound_data_tmp.sql +++ b/source/expectations/data_values/ut_compound_data_tmp.sql @@ -18,5 +18,5 @@ create global temporary table ut_compound_data_tmp( item_hash raw(128), pk_hash raw(128), duplicate_no integer, - constraint ut_cmp_data_tmp_hash_pk unique (data_id,item_no, item_hash , duplicate_no) -) on commit preserve rows; + constraint ut_cmp_data_tmp_hash_pk unique (data_id, item_no, duplicate_no) +) on commit preserve rows; \ No newline at end of file diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 0d93e2abf..0fe5544f7 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -23,14 +23,14 @@ create or replace type body ut_data_value_refcursor as end; member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) is - c_bulk_rows constant integer := 5000; + c_bulk_rows constant integer := 10000; l_cursor sys_refcursor := a_value; l_ctx number; l_xml xmltype; l_current_date_format varchar2(4000); cursor_not_open exception; l_ut_owner varchar2(250) := ut_utils.ut_owner; - l_set_id integer := 1; + l_set_id integer := 0; begin self.is_data_null := ut_utils.boolean_to_int(a_value is null); @@ -72,7 +72,7 @@ create or replace type body ut_data_value_refcursor as 'values (:self_guid, :self_row_count, :l_xml)' using in self.data_id, l_set_id, l_xml; - l_set_id := l_set_id + 1; + l_set_id := l_set_id + c_bulk_rows; end loop; ut_expectation_processor.reset_nls_params(); From c633ff5eab7c77c7a3fdaf393cdc90f18f60f18d Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 11 Nov 2018 20:43:08 +0000 Subject: [PATCH 46/83] Update code with bug fixes --- .../data_values/ut_compound_data_helper.pkb | 185 ++++++++---------- .../data_values/ut_compound_data_helper.pks | 5 +- .../data_values/ut_compound_data_tmp.sql | 2 +- .../data_values/ut_compound_data_value.tpb | 34 ++-- .../ut_curr_usr_compound_helper.pkb | 9 + .../ut_curr_usr_compound_helper.pks | 2 + .../data_values/ut_data_value_anydata.tpb | 2 + .../data_values/ut_data_value_refcursor.tpb | 7 +- .../data_values/ut_data_value_refcursor.tps | 4 + .../expectations/test_expectations_cursor.pkb | 88 ++++++--- .../expectations/test_expectations_cursor.pks | 6 + 11 files changed, 186 insertions(+), 158 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 848dd9ddc..bdd56a71c 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -28,10 +28,10 @@ create or replace package body ut_compound_data_helper is begin l_result := '<'||l_key||' xml_valid_name="'||l_key; if l_data is of(ut_data_value_xmltype) then - l_result := l_result||'" sql_diffable="0" user_defined="1" >' ||trim( both '''' from (treat(l_data as ut_data_value_xmltype).to_string)); + l_result := l_result||'" sql_diffable="0">' ||trim( both '''' from (treat(l_data as ut_data_value_xmltype).to_string)); else l_is_diff := ut_curr_usr_compound_helper.is_sql_compare_int((treat(l_data as ut_data_value_varchar2).data_value)); - l_result := l_result||'" sql_diffable="'||l_is_diff||'" user_defined="0">' || ut_utils.xmlgen_escaped_string((treat(l_data as ut_data_value_varchar2).data_value)); + l_result := l_result||'" sql_diffable="'||l_is_diff||'">' || ut_utils.xmlgen_escaped_string((treat(l_data as ut_data_value_varchar2).data_value)); end if; l_result := l_result ||''; return xmltype(l_result); @@ -219,13 +219,13 @@ create or replace package body ut_compound_data_helper is union all select item_no as rn, case when exp_data_id is null then 'Extra:' else 'Missing:' end as diff_type, - xmlserialize(content (case when exp_data_id is null then act_item_data else exp_item_data end) no indent) diffed_row, + xmlserialize(content (extract((case when exp_data_id is null then act_item_data else exp_item_data end),'/*/*')) no indent) diffed_row, nvl2(:join_by,ut3.ut_compound_data_helper.get_pk_value(:join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value from ut_compound_data_diff_tmp i where diff_id = :diff_id and act_data_id is null or exp_data_id is null ) - order by 2, 1]' + order by rn ,diff_type ]' bulk collect into l_results using a_exclude_xpath, a_include_xpath, a_join_by_xpath, a_diff_id, a_expected_dataset_guid, @@ -244,12 +244,11 @@ create or replace package body ut_compound_data_helper is l_results tt_row_diffs; begin l_column_filter := get_columns_filter(a_exclude_xpath,a_include_xpath); - execute immediate q'[ with - diff_info as ( select item_no ,exp_item_data, act_item_data,exp_data_id, act_data_id + diff_info as ( select item_no from - (select item_no,exp_item_data,exp_data_id, act_item_data, act_data_id from ut_compound_data_diff_tmp ucdc where diff_id = :diff_guid order by item_no asc) + (select item_no from ut_compound_data_diff_tmp ucdc where diff_id = :diff_guid order by item_no asc) where rownum <= :max_rows) select * from (select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, null pk_value @@ -258,30 +257,24 @@ create or replace package body ut_compound_data_helper is xmlagg(act.col order by act.col_no) act_item from (select r.item_no as rn, rownum col_no, s.column_value col, s.column_value.getRootElement() col_name, - s.column_value.getclobval() col_val, - r.data_id - from ( - select ]'||l_column_filter||q'[, ucd.item_no, ucd.exp_data_id as data_id - from - ( select exp_item_data as item_data, i.item_no, i.exp_data_id - from diff_info i - where i.exp_data_id = :self_guid - ) ucd + s.column_value.getclobval() col_val + from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_data item_data_no_filter + from ut_compound_data_tmp ucd, + diff_info i + where ucd.data_id = :self_guid + and ucd.item_no = i.item_no ) r, table( xmlsequence( extract(r.item_data,'/*/*') ) ) s ) exp - join ( + join ( select item_no as rn, rownum col_no, s.column_value col, s.column_value.getRootElement() col_name, - s.column_value.getclobval() col_val, - r.data_id - from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.act_data_id as data_id - from - ( - select act_item_data as item_data, i.item_no,i.act_data_id - from diff_info i - where i.act_data_id = :other_guid - ) ucd + s.column_value.getclobval() col_val + from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_data item_data_no_filter + from ut_compound_data_tmp ucd, + diff_info i + where ucd.data_id = :other_guid + and ucd.item_no = i.item_no ) r, table( xmlsequence( extract(r.item_data,'/*/*') ) ) s ) act @@ -293,20 +286,22 @@ create or replace package body ut_compound_data_helper is ) union all select nvl(exp.item_no, act.item_no) rn, - case when exp.data_id is null then 'Extra:' else 'Missing:' end as diff_type, - xmlserialize(content (case when exp.data_id is null then act.item_data else exp.item_data end) no indent) diffed_row, + case when exp.item_no is null then 'Extra:' else 'Missing:' end as diff_type, + xmlserialize(content nvl(exp.item_data, act.item_data) no indent) diffed_row, null pk_value - from (select ucd.item_no, extract(ucd.exp_item_data,'/*/*') item_data, ucd.exp_data_id data_id - from diff_info ucd - where ucd.exp_data_id = :self_guid + from (select ucd.item_no, extract(ucd.item_data,'/*/*') item_data + from ut_compound_data_tmp ucd + where ucd.data_id = :self_guid + and ucd.item_no in (select i.item_no from diff_info i) ) exp full outer join ( - select ucd.item_no, extract(ucd.act_item_data,'/*/*') item_data, ucd.act_data_id data_id - from diff_info ucd - where ucd.act_data_id = :other_guid + select ucd.item_no, extract(ucd.item_data,'/*/*') item_data + from ut_compound_data_tmp ucd + where ucd.data_id = :other_guid + and ucd.item_no in (select i.item_no from diff_info i) )act on exp.item_no = act.item_no - where exp.data_id is null or act.data_id is null + where exp.item_no is null or act.item_no is null order by 1, 2]' bulk collect into l_results using a_diff_id, a_max_rows, @@ -319,12 +314,12 @@ create or replace package body ut_compound_data_helper is function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unordered boolean + a_join_by_xpath varchar2,a_refcursor boolean ) return tt_row_diffs is l_result tt_row_diffs := tt_row_diffs(); begin case - when a_unordered then + when a_refcursor then l_result := get_rows_diff_by_sql(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, a_max_rows, a_exclude_xpath, a_include_xpath ,a_join_by_xpath); else @@ -426,19 +421,15 @@ create or replace package body ut_compound_data_helper is is_sql_diff varchar2(4000) PATH '@sql_diffable' ) xt, table(a_column_info) t - where xt.name = t.column_value) + where '"'||xt.name||'"' = t.column_value) loop if i.is_sql_diff = 0 then - l_col_syntax := l_ut_owner ||'.ut_compound_data_helper.get_hash('||l_alias||i.column_value||'.getClobVal()) as '|| i.column_value ; + l_col_syntax := l_ut_owner ||'.ut_compound_data_helper.get_hash('||l_alias||i.column_value||'.getClobVal()) as '||i.column_value ; else - l_col_syntax := l_alias||i.column_value||' as '|| i.column_value ; + l_col_syntax := l_alias||i.column_value||' as '|| i.column_value; end if; - l_sql_stmt := l_sql_stmt || case - when l_sql_stmt is null then - null - else ',' - end||l_col_syntax; + l_sql_stmt := l_sql_stmt ||','||l_col_syntax; end loop; return l_sql_stmt; end; @@ -448,15 +439,19 @@ create or replace package body ut_compound_data_helper is l_alias varchar2(10) := 'ucd.'; begin - for i in 1..a_column_info.count - loop - l_sql_stmt := l_sql_stmt || case + if a_column_info.count > 0 or a_column_info is null then + for i in 1..a_column_info.count + loop + l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ',' end||l_alias||a_column_info(i); - end loop; - l_sql_stmt := 'row_number() over (partition by '|| l_sql_stmt || ' order by '||l_sql_stmt||' ) dup_no '; + end loop; + l_sql_stmt := ', row_number() over (partition by '|| l_sql_stmt || ' order by '||l_sql_stmt||' ) dup_no '; + else + l_sql_stmt := ', 1 dup_no '; + end if; return l_sql_stmt; end; @@ -480,21 +475,19 @@ create or replace package body ut_compound_data_helper is is_sql_diff varchar2(4000) PATH '@sql_diffable' ) xt, table(a_column_info) t - where xt.name = t.column_value) + where '"'||xt.name||'"' = t.column_value) loop if i.is_sql_diff = 0 then l_col_type := 'XMLTYPE'; elsif i.is_sql_diff = 1 and (i.type IN ('CHAR','VARCHAR2','VARCHAR')) then l_col_type := 'VARCHAR2(4000)'; + elsif i.is_sql_diff = 1 and i.type = 'DATE' then + l_col_type := 'TIMESTAMP'; else l_col_type := i.type; end if; - l_sql_stmt := l_sql_stmt || case - when l_sql_stmt is null then - null - else ',' - end ||i.column_value||' '||l_col_type||q'[ PATH ']'||i.column_value||q'[']'; + l_sql_stmt := l_sql_stmt||i.column_value||' '||l_col_type||q'[ PATH ']'||TRIM(BOTH '"' FROM i.column_value)||q'[',]'; end loop; return l_sql_stmt; end; @@ -527,12 +520,12 @@ create or replace package body ut_compound_data_helper is is_sql_diff varchar2(4000) PATH '@sql_diffable' ) xt, table(a_join_by_xpath_tab) t - where xt.name = t.column_value) + where '"'||xt.name||'"' = t.column_value) loop if i.is_sql_diff = 0 then - l_non_diff_var := l_ut_owner ||'.ut_compound_data_helper.get_hash((extract( a.'||i.column_value||','||a_join_by_xpath||')).getclobval()) = ' - ||l_ut_owner ||'.ut_compound_data_helper.get_hash((extract( e.'||i.column_value||','||a_join_by_xpath||')).getclobval())'; + l_non_diff_var := l_ut_owner ||'.ut_compound_data_helper.get_hash((extract( a.'||i.column_value||', '||a_join_by_xpath||')).getclobval()) = ' + ||l_ut_owner ||'.ut_compound_data_helper.get_hash((extract( e.'||i.column_value||', '||a_join_by_xpath||')).getclobval())'; l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.column_value||q'[ = ]'||' e.'||i.column_value; elsif i.is_sql_diff = 1 then l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.column_value||q'[ = ]'||' e.'||i.column_value; @@ -548,7 +541,7 @@ create or replace package body ut_compound_data_helper is begin for i in ( with xpaths_tab as (select column_value xpath from table(a_join_by_xpath)), - pk_names as (select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$') name + pk_names as (select '"'||REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$')||'"' name from xpaths_tab) select /*+ CARDINALITY(xt 100) */ column_value as name @@ -569,36 +562,23 @@ create or replace package body ut_compound_data_helper is l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); l_act_col_tab ut_varchar2_list := ut_varchar2_list(); - + l_ut_owner varchar2(250) := ut_utils.ut_owner; l_xmltable_stmt clob; l_where_stmt clob; l_select_stmt clob; l_partition_stmt clob; + l_column_filter varchar2(32767); - function get_columns_names (a_xpath_tab in ut_varchar2_list) return ut_varchar2_list is - l_names_tab ut_varchar2_list := ut_varchar2_list(); - begin - select distinct REGEXP_SUBSTR (column_value,'[^(\/*\/)]+',1,1) - bulk collect into l_names_tab - from table(a_xpath_tab); - return l_names_tab; - end; - - function get_columns_info (a_columns_info in xmltype) return ut_varchar2_list is + function get_filtered_columns_name (a_columns_info in xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2) return ut_varchar2_list is l_columns_info ut_varchar2_list := ut_varchar2_list(); begin - select /*+ CARDINALITY(xt 100) */ - distinct xt.name - bulk collect into l_columns_info - from (select a_column_info item_data from dual) x, - xmltable( - '/ROW/*' - passing x.item_data - columns - name varchar2(4000) PATH '@xml_valid_name' - ) xt; - return l_columns_info; + execute immediate 'with xmlt as ( select :xml_data as item_data from dual ),' + ||'filtered as (select '||get_columns_row_filter(a_exclude_xpath,a_include_xpath) ||' from xmlt ucd) ' + ||q'[select '"'||xt.name||'"' from filtered f, xmltable( '/ROW/*' passing f.item_data columns ]' + ||q'[name VARCHAR2(4000) PATH '@xml_valid_name') xt]' bulk collect into l_columns_info + using a_columns_info,a_exclude_xpath,a_include_xpath; + return l_columns_info; end; function get_join_type(a_inclusion_compare in boolean,a_negated in boolean) return varchar2 is @@ -617,28 +597,21 @@ create or replace package body ut_compound_data_helper is --TODO: Resolve issues with collection and nested tables, can we extract by internal column name if defined e.g. xml of colval.id.getclobval() --TODO: Comment better all pieces - --Check include and exclude columns and create an actual column list that have to be compared. - if a_include_xpath is null and a_exclude_xpath is null then - l_act_col_tab := get_columns_info(a_column_info); - elsif a_include_xpath is not null and a_exclude_xpath is null then - l_act_col_tab := get_columns_names(ut_utils.string_to_table(a_include_xpath,'|')); - elsif a_include_xpath is null and a_exclude_xpath is not null then - l_act_col_tab := get_columns_info(a_column_info) multiset except get_columns_names(ut_utils.string_to_table(a_exclude_xpath,'|')); - elsif a_include_xpath is not null and a_exclude_xpath is not null then - l_act_col_tab := get_columns_names(ut_utils.string_to_table(a_include_xpath,'|')) multiset except get_columns_names(ut_utils.string_to_table(a_exclude_xpath,'|')); - end if; + l_column_filter := get_columns_row_filter(a_exclude_xpath, a_include_xpath); - l_pk_xpath_tabs := get_columns_names(ut_utils.string_to_table(a_join_by_xpath,'|')); + l_act_col_tab := get_filtered_columns_name(a_column_info,a_exclude_xpath,a_include_xpath); + + l_pk_xpath_tabs := get_filtered_columns_name(a_column_info,null,a_join_by_xpath); l_xmltable_stmt := generate_xmltab_stmt(l_act_col_tab,a_column_info); l_select_stmt := generate_select_stmt(l_act_col_tab,a_column_info); l_partition_stmt := generate_partition_stmt(l_act_col_tab); - l_temp_string := 'with exp as ( select ucd.* , '; + l_temp_string := 'with exp as ( select ucd.* '; ut_utils.append_to_clob(l_compare_sql, l_temp_string); - ut_utils.append_to_clob(l_compare_sql, l_partition_stmt); + ut_utils.append_to_clob(l_compare_sql,l_partition_stmt); - l_temp_string := 'from (select ucd.item_data, '; + l_temp_string := 'from (select ucd.item_data '; ut_utils.append_to_clob(l_compare_sql, l_temp_string); ut_utils.append_to_clob(l_compare_sql, l_select_stmt); @@ -654,14 +627,14 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt); - l_temp_string := q'[ ,item_data xmltype PATH '*' ) ucd where data_id = :self_guid ) ucd ) ,]'; + l_temp_string := q'[ item_data xmltype PATH '*' ) ucd where data_id = :self_guid ) ucd ) ,]'; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - l_temp_string :='act as ( select ucd.* , '; + l_temp_string :='act as ( select ucd.* '; ut_utils.append_to_clob(l_compare_sql, l_temp_string); ut_utils.append_to_clob(l_compare_sql, l_partition_stmt); - l_temp_string := 'from (select ucd.item_data, '; + l_temp_string := 'from (select ucd.item_data '; ut_utils.append_to_clob(l_compare_sql,l_temp_string); ut_utils.append_to_clob(l_compare_sql, l_select_stmt); @@ -675,7 +648,7 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql,'POSITION for ordinality, '); end if; - ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt||q'[ ,item_data xmltype PATH '*') ucd where data_id = :other_guid ) ucd ) ]'); + ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt||q'[ item_data xmltype PATH '*') ucd where data_id = :other_guid ) ucd ) ]'); l_temp_string := ' select a.item_data as act_item_data, a.data_id act_data_id,' ||'e.item_data as exp_item_data, e.data_id exp_data_id, '|| @@ -699,16 +672,18 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql,' ) where '); - if (a_join_by_xpath is not null) and (a_unordered) and (a_inclusion_type) and (not a_is_negated) then + if (a_join_by_xpath is not null) and (a_unordered) and (not a_is_negated) then l_where_stmt := generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); if l_where_stmt is not null then ut_utils.append_to_clob(l_compare_sql,' ( '||l_where_stmt||' ) or '); end if; elsif not a_unordered then l_where_stmt := generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); - ut_utils.append_to_clob(l_compare_sql,' ( '||l_where_stmt||' ) or '); + if l_where_stmt is not null then + ut_utils.append_to_clob(l_compare_sql,' ( '||l_where_stmt||' ) or '); + end if; end if; - + --If its inlcusion we expect a actual set to fully match and have no extra elements over expected if a_inclusion_type and not(a_is_negated) then l_temp_string := ' ( a.data_id is null ) '; @@ -716,7 +691,7 @@ create or replace package body ut_compound_data_helper is l_temp_string := ' (a.data_id is null or e.data_id is null) '; end if; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - + return l_compare_sql; end; @@ -742,7 +717,7 @@ create or replace package body ut_compound_data_helper is g_diff_count := 0; end; - function get_rows_diff return integer is + function get_rows_diff_count return integer is begin return g_diff_count; end; diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index a73fae8dd..0d7a460a7 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -71,10 +71,11 @@ create or replace package ut_compound_data_helper authid definer is function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob; + --TODO : Can this be done better ?? function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unordered boolean + a_join_by_xpath varchar2,a_refcursor boolean ) return tt_row_diffs; subtype t_hash is raw(128); @@ -99,7 +100,7 @@ create or replace package ut_compound_data_helper authid definer is procedure cleanup_diff; - function get_rows_diff return integer; + function get_rows_diff_count return integer; end; / diff --git a/source/expectations/data_values/ut_compound_data_tmp.sql b/source/expectations/data_values/ut_compound_data_tmp.sql index 1d471362f..7beb1e9cd 100644 --- a/source/expectations/data_values/ut_compound_data_tmp.sql +++ b/source/expectations/data_values/ut_compound_data_tmp.sql @@ -19,4 +19,4 @@ create global temporary table ut_compound_data_tmp( pk_hash raw(128), duplicate_no integer, constraint ut_cmp_data_tmp_hash_pk unique (data_id, item_no, duplicate_no) -) on commit preserve rows; \ No newline at end of file +) on commit preserve rows xmltype column item_data store as binary xml; \ No newline at end of file diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index cdec16b98..cb5d5aa2c 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -53,10 +53,13 @@ create or replace type body ut_compound_data_value as --return first c_max_rows rows execute immediate ' select xmlserialize( content ucd.item_data no indent) - from '|| ut_utils.ut_owner ||'.ut_compound_data_tmp ucd - where ucd.data_id = :data_id - and ucd.item_no <= :max_rows' - bulk collect into l_results using self.data_id, c_max_rows; + from '|| ut_utils.ut_owner ||q'[.ut_compound_data_tmp tmp + ,xmltable ( '/ROWSET' passing tmp.item_data + columns item_data xmltype PATH '*' + ) ucd + where tmp.data_id = :data_id + and rownum <= :max_rows]' + bulk collect into l_results using self.data_id, ut_utils.gc_diff_max_rows; ut_utils.append_to_clob(l_result,l_results); @@ -113,18 +116,15 @@ create or replace type body ut_compound_data_value as dbms_lob.createtemporary(l_result,true); - --diff rows and row elements l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); - + -- First tell how many rows are different - - --TODO: that is a bit mess ?? Can we use global variable for all matchers. - l_diff_row_count := ut_compound_data_helper.get_rows_diff; - + l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; + if l_diff_row_count > 0 then l_row_diffs := ut_compound_data_helper.get_rows_diff( self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, - a_include_xpath, a_join_by_xpath, a_unordered); + a_include_xpath, a_join_by_xpath, a_other is of (ut_data_value_refcursor)); l_message := chr(10) ||'Rows: [ ' || l_diff_row_count ||' differences' || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end @@ -168,7 +168,7 @@ create or replace type body ut_compound_data_value as if not a_other is of (ut_compound_data_value) then raise value_error; end if; - + l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); @@ -194,7 +194,7 @@ create or replace type body ut_compound_data_value as if sql%rowcount = 0 and self.elements_count = l_other.elements_count then l_result := 0; else - ut_compound_data_helper.set_rows_diff(sql%rowcount); + ut_compound_data_helper.set_rows_diff(sql%rowcount); l_result := 1; end if; return l_result; @@ -216,10 +216,11 @@ create or replace type body ut_compound_data_value as begin --TODO : Error on xml when same column is more then once in item data xml.Do we need to cleanup ?? --TODO : Bring diffs row into same place for ref data cursor especially (how we going to do that so we dont break anyval etc) + --TODO : Test binary xml storage (didnt seems to make a diffrence, docker and datafiles layer ??) l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - open l_loop_curs for ut_compound_data_helper.gen_compare_sql(treat(a_other as ut_data_value_refcursor).columns_info, a_exclude_xpath, + open l_loop_curs for ut_compound_data_helper.gen_compare_sql(treat(a_other as ut_data_value_refcursor).col_info_desc, a_exclude_xpath, a_include_xpath, a_join_by_xpath, a_inclusion_compare, a_is_negated, a_unordered ) using self.data_id,l_other.data_id; loop fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; @@ -233,15 +234,14 @@ create or replace type body ut_compound_data_value as if (ut_utils.gc_diff_max_rows <= l_sql_rowcount and l_max_rows != ut_utils.gc_bc_fetch_limit ) then l_max_rows := ut_utils.gc_bc_fetch_limit; end if; - end loop; - + end loop; --result is OK only if both are same if l_sql_rowcount = 0 and ( self.elements_count = l_other.elements_count or a_inclusion_compare )then l_result := 0; else ut_compound_data_helper.set_rows_diff(l_sql_rowcount); l_result := 1; - end if; + end if; return l_result; diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb index 8ea1ab5bb..0cf12f633 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb @@ -232,6 +232,15 @@ create or replace package body ut_curr_usr_compound_helper is return l_result; end; + function extract_min_col_info(a_full_col_info xmltype) return xmltype is + l_result xmltype; + begin + SELECT deleteXML(a_full_col_info,'/ROW/*/@sql_diffable') + into l_result + from dual; + return l_result ; + end; + begin g_anytype_name_map(dbms_types.typecode_date) := 'DATE'; g_anytype_name_map(dbms_types.typecode_number) := 'NUMBER'; diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pks b/source/expectations/data_values/ut_curr_usr_compound_helper.pks index bbbba0fa3..b4230a29d 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pks +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pks @@ -13,5 +13,7 @@ create or replace package ut_curr_usr_compound_helper authid current_user is function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return xmltype; + function extract_min_col_info(a_full_col_info xmltype) return xmltype; + end; / diff --git a/source/expectations/data_values/ut_data_value_anydata.tpb b/source/expectations/data_values/ut_data_value_anydata.tpb index 7d5322cca..0be830afb 100644 --- a/source/expectations/data_values/ut_data_value_anydata.tpb +++ b/source/expectations/data_values/ut_data_value_anydata.tpb @@ -36,6 +36,8 @@ create or replace type body ut_data_value_anydata as else self.is_data_null := 1; end if; + + ut_compound_data_helper.cleanup_diff; if not self.is_null() then ut_expectation_processor.set_xml_nls_params(); open l_query for select a_value val from dual; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 0fe5544f7..42b65ecf2 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -37,13 +37,16 @@ create or replace type body ut_data_value_refcursor as self.self_type := $$plsql_unit; self.data_id := sys_guid(); self.data_type := 'refcursor'; + ut_compound_data_helper.cleanup_diff; + if l_cursor is not null then if l_cursor%isopen then --Get some more info regarding cursor, including if it containts collection columns and what is their name - ut_curr_usr_compound_helper.get_columns_info(l_cursor,self.columns_info,self.key_info, + ut_curr_usr_compound_helper.get_columns_info(l_cursor,self.col_info_desc,self.key_info, self.contain_collection); self.elements_count := 0; + self.columns_info := ut_curr_usr_compound_helper.extract_min_col_info(self.col_info_desc); -- We use DBMS_XMLGEN in order to: -- 1) be able to process data in bulks (set of rows) @@ -80,7 +83,7 @@ create or replace type body ut_data_value_refcursor as close l_cursor; end if; dbms_xmlgen.closeContext(l_ctx); - + elsif not l_cursor%isopen then raise cursor_not_open; end if; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 36c231887..29ee3b702 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -35,6 +35,10 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( */ columns_info xmltype, + /** + * Holds information about column names and column data-types and also some supporting attributes + */ + col_info_desc xmltype, /** * Holds more detailed information regarding the pk joins */ diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 1ac1a7485..bb5221d4d 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -62,6 +62,7 @@ create or replace package body test_expectations_cursor is l_actual sys_refcursor; begin -- Arrange + ut.set_nls; open l_expected for select 1 as my_num, 'This is my test string' as my_string, @@ -74,6 +75,7 @@ create or replace package body test_expectations_cursor is to_clob('This is an even longer test clob') as my_clob, to_date('1984-09-05', 'YYYY-MM-DD') as my_date from dual; + ut.reset_nls; --Act ut3.ut.expect( l_actual ).to_equal( l_expected ); --Assert @@ -661,9 +663,7 @@ Diff: Columns: Column is misplaced. Expected position: 2, actual position: 4. Column is misplaced. Expected position: 3, actual position: 2. - Column is misplaced. Expected position: 4, actual position: 3. -Rows: [ 2 differences ] - All rows are different as the columns are not matching.]'; + Column is misplaced. Expected position: 4, actual position: 3.]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -893,8 +893,8 @@ Rows: [ 4 differences ] l_expected sys_refcursor; begin --Arrange - open l_actual for select object_name from all_objects where rownum <=1100; - open l_expected for select object_name from all_objects where rownum <=1100; + open l_actual for select object_name from all_objects where rownum <=1100 order by object_id; + open l_expected for select object_name from all_objects where rownum <=1100 order by object_id; --Act ut3.ut.expect(l_actual).to_equal(l_expected); @@ -908,8 +908,8 @@ Rows: [ 4 differences ] l_expected sys_refcursor; begin --Arrange - open l_actual for select object_name from all_objects where rownum <=11000; - open l_expected for select object_name from all_objects where rownum <=11000; + open l_actual for select object_name from all_objects where rownum <=11000 order by object_id; + open l_expected for select object_name from all_objects where rownum <=11000 order by object_id; --Act ut3.ut.expect(l_actual).to_equal(l_expected); @@ -1090,8 +1090,8 @@ Rows: [ 2 differences ]% l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ]% %Diff:% %Rows: [ 2 differences ]% -%Extra: test-666% -%Missing: test-667%]'; +%Extra: test-666% +%Missing: test-667%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -1289,6 +1289,32 @@ Diff:% ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + procedure cursor_unorder_compare_1000 is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select level object_id, level || '_TEST' object_name from dual connect by level <=1100; + open l_expected for select level object_id, level || '_TEST' object_name from dual connect by level <=1100; + --Act + ut3.ut.expect(l_actual).to_equal(l_expected).unordered; + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure cursor_unorder_compare_10000 is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select level object_id, level || '_TEST' object_name from dual connect by level <=11000; + open l_expected for select level object_id, level || '_TEST' object_name from dual connect by level <=11000; + --Act + ut3.ut.expect(l_actual).to_equal(l_expected).unordered; + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + procedure cursor_joinby_compare_fail is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; @@ -1334,8 +1360,8 @@ Diff:% l_expected_message := q'[%Actual: refcursor [ count = % ] was expected to equal: refcursor [ count = % ] %Diff:% %Rows: [ 2 differences ]% -%PK TEST-610 - Extra: TEST-610% -%PK TEST-600 - Missing: TEST-600%]'; +%PK TEST-610 - Extra: TEST-610% +%PK TEST-600 - Missing: TEST-600%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -1516,12 +1542,12 @@ Diff:% ut3.ut.expect(l_actual).to_equal(l_expected).unordered; l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 3 ]% Diff:% -Rows: [ 5 differences ] -%Extra: 2Something 22% -%Extra: 1Something 11% -%Missing: 1Somethings 11% -%Missing: 2Somethings 22% -%Missing: 3Somethings 33%]'; +Rows: [ 5 differences 1 +%Extra: 1Something 11% +%Extra: 2Something 22% +%Missing: 1Somethings 11% +%Missing: 2Somethings 22% +%Missing: 3Somethings 33%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -2036,7 +2062,7 @@ Diff:% l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 3 ] %Diff: %Rows: [ 1 differences ] -%Missing: Table%]'; +%Missing: Table%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -2077,11 +2103,11 @@ Diff:% l_expected_message := q'[%Actual: refcursor [ count = 4 ] was expected to include: refcursor [ count = 9 ] %Diff: %Rows: [ 5 differences ] -%Missing: %%% -%Missing: %%% -%Missing: %%% -%Missing: %%% -%Missing: %%%%]'; +%Missing: %%%% +%Missing: %%%% +%Missing: %%%% +%Missing: %%%% +%Missing: %%%%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -2121,11 +2147,11 @@ Diff:% l_expected_message := q'[%Actual: refcursor [ count = 4 ] was expected to include: refcursor [ count = 9 ] %Diff: %Rows: [ 5 differences ] -%Missing: %%% -%Missing: %%% -%Missing: %%% -%Missing: %%% -%Missing: %%%%]'; +%Missing: %%%% +%Missing: %%%% +%Missing: %%%% +%Missing: %%%% +%Missing: %%%%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -2478,9 +2504,9 @@ Diff:% l_expected_message := q'[%Actual: refcursor [ count = 9 ] was expected to include: refcursor [ count = 6 ] %Diff: %Rows: [ 3 differences ] -%Missing: % -%Missing: % -%Missing: %]'; +%Missing: % +%Missing: % +%Missing: %]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index 42d6f8cab..e70bb8cdf 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -237,6 +237,12 @@ create or replace package test_expectations_cursor is --%test( Compare cursors join by single key more than 10000 rows) procedure cursor_joinby_compare_10000; + + --%test( Compare cursors unorder more than 1000 rows) + procedure cursor_unorder_compare_1000; + + --%test( Compare cursors unorder more than 10000 rows) + procedure cursor_unorder_compare_10000; --%test( Compare two column cursors join by and fail to match ) procedure cursor_joinby_compare_fail; From ee7bdf27988eb33cd6bd5bfd33a92946ac2eef94 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 11 Nov 2018 21:45:08 +0000 Subject: [PATCH 47/83] Update order --- .../data_values/ut_compound_data_helper.pkb | 16 ++++++++++++---- 1 file changed, 12 insertions(+), 4 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index bdd56a71c..ac9c8af78 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -183,7 +183,7 @@ create or replace package body ut_compound_data_helper is l_act_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','act_item_data'); l_exp_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','exp_item_data'); - --TODO: Generate a dynamic SQL based on input e.g. no need for PK during unordered and consolidate get_rows_diff + --TODO: Generate SQL based on input as unorder join should aggregate execute immediate q'[with exp as ( select exp_item_data, exp_data_id, item_no rn,rownum col_no, @@ -209,23 +209,31 @@ create or replace package body ut_compound_data_helper is ) select rn, diff_type, diffed_row, pk_value pk_value from ( + select rn, diff_type, diffed_row, pk_value + ,case when diff_type = 'Actual:' then 1 else 2 end rnk + ,1 final_order + from ( select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value from - (select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item + (select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item from exp join act on exp.rn = act.rn and exp.col_name = act.col_name where dbms_lob.compare(exp.col_val, act.col_val) != 0) unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') - ) + )) union all select item_no as rn, case when exp_data_id is null then 'Extra:' else 'Missing:' end as diff_type, xmlserialize(content (extract((case when exp_data_id is null then act_item_data else exp_item_data end),'/*/*')) no indent) diffed_row, nvl2(:join_by,ut3.ut_compound_data_helper.get_pk_value(:join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value + ,case when exp_data_id is null then 1 else 2 end rnk + ,2 final_order from ut_compound_data_diff_tmp i where diff_id = :diff_id and act_data_id is null or exp_data_id is null ) - order by rn ,diff_type ]' + order by final_order, + case when final_order = 1 then rn else rnk end, + case when final_order = 1 then rnk else rn end ]' bulk collect into l_results using a_exclude_xpath, a_include_xpath, a_join_by_xpath, a_diff_id, a_expected_dataset_guid, From 5b46ab0a3374659b4e07167d6544be96ca6d74c4 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Mon, 12 Nov 2018 06:55:46 +0000 Subject: [PATCH 48/83] Updated code for tests. --- .../data_values/ut_compound_data_helper.pkb | 38 ++++++++++++++----- .../data_values/ut_compound_data_helper.pks | 2 +- .../data_values/ut_compound_data_value.tpb | 2 +- 3 files changed, 30 insertions(+), 12 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index ac9c8af78..c75543ef3 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -172,20 +172,20 @@ create or replace package body ut_compound_data_helper is function get_rows_diff_by_sql( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2 + a_join_by_xpath varchar2, a_unordered boolean ) return tt_row_diffs is l_act_col_filter varchar2(32767); l_exp_col_filter varchar2(32767); l_results tt_row_diffs; - + l_sql varchar2(32767); begin l_act_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','act_item_data'); l_exp_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','exp_item_data'); --TODO: Generate SQL based on input as unorder join should aggregate - execute immediate q'[with exp as ( + l_sql := q'[with exp as ( select exp_item_data, exp_data_id, item_no rn,rownum col_no, nvl2(exp_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,exp_item_data),null) pk_value, s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val @@ -212,15 +212,31 @@ create or replace package body ut_compound_data_helper is select rn, diff_type, diffed_row, pk_value ,case when diff_type = 'Actual:' then 1 else 2 end rnk ,1 final_order - from ( - select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value + from ( ]'; + + if a_unordered then + l_sql := l_sql || q'[select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value from (select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item from exp join act on exp.rn = act.rn and exp.col_name = act.col_name where dbms_lob.compare(exp.col_val, act.col_val) != 0) unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') - )) - union all + ))]'; + else + l_sql := l_sql || q'[ select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, null pk_value + from + (select nvl(exp.rn, act.rn) rn, + xmlagg(exp.col order by exp.col_no) exp_item, + xmlagg(act.col order by act.col_no) act_item + from exp exp join act act on exp.rn = act.rn and exp.col_name = act.col_name + where dbms_lob.compare(exp.col_val, act.col_val) != 0 + group by exp.rn, act.rn + ) + unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:')) + )]'; + end if; + + l_sql := l_sql || q'[union all select item_no as rn, case when exp_data_id is null then 'Extra:' else 'Missing:' end as diff_type, xmlserialize(content (extract((case when exp_data_id is null then act_item_data else exp_item_data end),'/*/*')) no indent) diffed_row, @@ -233,7 +249,9 @@ create or replace package body ut_compound_data_helper is ) order by final_order, case when final_order = 1 then rn else rnk end, - case when final_order = 1 then rnk else rn end ]' + case when final_order = 1 then rnk else rn end ]'; + + execute immediate l_sql bulk collect into l_results using a_exclude_xpath, a_include_xpath, a_join_by_xpath, a_diff_id, a_expected_dataset_guid, @@ -322,14 +340,14 @@ create or replace package body ut_compound_data_helper is function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_refcursor boolean + a_join_by_xpath varchar2,a_refcursor boolean, a_unordered boolean ) return tt_row_diffs is l_result tt_row_diffs := tt_row_diffs(); begin case when a_refcursor then l_result := get_rows_diff_by_sql(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, - a_max_rows, a_exclude_xpath, a_include_xpath ,a_join_by_xpath); + a_max_rows, a_exclude_xpath, a_include_xpath ,a_join_by_xpath, a_unordered); else l_result := get_rows_diff(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, a_max_rows, a_exclude_xpath, a_include_xpath); diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 0d7a460a7..046191aa1 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -75,7 +75,7 @@ create or replace package ut_compound_data_helper authid definer is function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_refcursor boolean + a_join_by_xpath varchar2,a_refcursor boolean, a_unordered boolean ) return tt_row_diffs; subtype t_hash is raw(128); diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index cb5d5aa2c..51b2e22cc 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -124,7 +124,7 @@ create or replace type body ut_compound_data_value as if l_diff_row_count > 0 then l_row_diffs := ut_compound_data_helper.get_rows_diff( self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, - a_include_xpath, a_join_by_xpath, a_other is of (ut_data_value_refcursor)); + a_include_xpath, a_join_by_xpath, a_other is of (ut_data_value_refcursor), a_unordered); l_message := chr(10) ||'Rows: [ ' || l_diff_row_count ||' differences' || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end From c997616408c5479a1e16e99aad24b14f91a86ed2 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Tue, 13 Nov 2018 08:36:00 +0000 Subject: [PATCH 49/83] Added cursor info code --- source/core/types/ut_cursor_info.tps | 22 +++ .../data_values/ut_column_info.tpb | 29 ++++ .../data_values/ut_column_info.tps | 25 ++++ .../data_values/ut_column_info_rec.tpb | 131 ++++++++++++++++++ .../data_values/ut_column_info_rec.tps | 28 ++++ .../data_values/ut_column_info_tab.tps | 2 + .../data_values/ut_cursor_info.tpb | 31 +++++ .../data_values/ut_cursor_info.tps | 7 + 8 files changed, 275 insertions(+) create mode 100644 source/core/types/ut_cursor_info.tps create mode 100644 source/expectations/data_values/ut_column_info.tpb create mode 100644 source/expectations/data_values/ut_column_info.tps create mode 100644 source/expectations/data_values/ut_column_info_rec.tpb create mode 100644 source/expectations/data_values/ut_column_info_rec.tps create mode 100644 source/expectations/data_values/ut_column_info_tab.tps create mode 100644 source/expectations/data_values/ut_cursor_info.tpb create mode 100644 source/expectations/data_values/ut_cursor_info.tps diff --git a/source/core/types/ut_cursor_info.tps b/source/core/types/ut_cursor_info.tps new file mode 100644 index 000000000..0577264f0 --- /dev/null +++ b/source/core/types/ut_cursor_info.tps @@ -0,0 +1,22 @@ +create or replace type ut_column_info as object ( + /* + utPLSQL - Version 3 + Copyright 2016 - 2018 utPLSQL Project + + Licensed under the Apache License, Version 2.0 (the "License"): + you may not use this file except in compliance with the License. + You may obtain a copy of the License at + + http://www.apache.org/licenses/LICENSE-2.0 + + Unless required by applicable law or agreed to in writing, software + distributed under the License is distributed on an "AS IS" BASIS, + WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + See the License for the specific language governing permissions and + limitations under the License. + */ +column_name varchar2(100), +xml_valid_name varchar2(100), + +) + diff --git a/source/expectations/data_values/ut_column_info.tpb b/source/expectations/data_values/ut_column_info.tpb new file mode 100644 index 000000000..5e913bf31 --- /dev/null +++ b/source/expectations/data_values/ut_column_info.tpb @@ -0,0 +1,29 @@ +create or replace type body ut_column_info as + member function get_data_type(a_type_code in integer,a_user_defined in boolean) return varchar2 is + begin + return ut_curr_usr_compound_helper.get_column_type(a_type_code,a_user_defined); + end; + + member procedure init(self in out nocopy ut_column_info, + a_col_type binary_integer, + a_col_name varchar2, + a_col_schema_name varchar2, + a_col_type_name varchar2, + a_col_prec integer, + a_col_scale integer, + a_col_len integer, + a_dbms_sql_desc boolean := false) is + begin + self.is_user_defined := 0; + self.column_prec := a_col_prec; + self.column_len := a_col_len; + self.column_scale := a_col_scale; + self.xml_valid_name := '"'||a_col_name||'"'; + self.column_name := a_col_name; + self.column_type := get_data_type(a_col_type,a_dbms_sql_desc); + self.column_schema := a_col_schema_name; + self.is_sql_diffable := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)); + self.is_collection := 0; + end; +end; +/ diff --git a/source/expectations/data_values/ut_column_info.tps b/source/expectations/data_values/ut_column_info.tps new file mode 100644 index 000000000..331ab3d2e --- /dev/null +++ b/source/expectations/data_values/ut_column_info.tps @@ -0,0 +1,25 @@ +create or replace type ut_column_info force authid current_user as object +( + xml_valid_name varchar2(100), + column_name varchar2(100), + column_type varchar2(100), + column_schema varchar2(100), + column_prec integer, + column_len integer, + column_scale integer, + is_sql_diffable number(1, 0), + is_collection number(1, 0), + is_user_defined number(1, 0), + member function get_data_type(a_type_code in integer,a_user_defined in boolean) return varchar2, + member procedure init(self in out nocopy ut_column_info, + a_col_type binary_integer, + a_col_name varchar2, + a_col_schema_name varchar2, + a_col_type_name varchar2, + a_col_prec integer, + a_col_scale integer, + a_col_len integer, + a_dbms_sql_desc boolean := false) +) +not final not instantiable +/ diff --git a/source/expectations/data_values/ut_column_info_rec.tpb b/source/expectations/data_values/ut_column_info_rec.tpb new file mode 100644 index 000000000..19d6ab13a --- /dev/null +++ b/source/expectations/data_values/ut_column_info_rec.tpb @@ -0,0 +1,131 @@ +create or replace type body ut_column_info_rec as + + member function get_anytype_attributes_info(a_anytype anytype) + return ut_column_info_tab is + l_result ut_column_info_tab := ut_column_info_tab(); + l_attribute_typecode pls_integer; + l_aname varchar2(32767); + l_prec pls_integer; + l_scale pls_integer; + l_len pls_integer; + l_csid pls_integer; + l_csfrm pls_integer; + l_attr_elt_type anytype; + + function get_anytype_attribute_count(a_anytype anytype) return pls_integer is + l_attribute_typecode pls_integer; + l_schema_name varchar2(32767); + l_version varchar2(32767); + l_type_name varchar2(32767); + l_attributes pls_integer; + l_prec pls_integer; + l_scale pls_integer; + l_len pls_integer; + l_csid pls_integer; + l_csfrm pls_integer; + begin + l_attribute_typecode := a_anytype.getinfo(prec => l_prec, + scale => l_scale, + len => l_len, + csid => l_csid, + csfrm => l_csfrm, + schema_name => l_schema_name, + type_name => l_type_name, + version => l_version, + numelems => l_attributes); + return l_attributes; + end; + + begin + for i in 1 .. get_anytype_attribute_count(a_anytype) loop + l_attribute_typecode := a_anytype.getattreleminfo(pos => i, --First attribute + prec => l_prec, + scale => l_scale, + len => l_len, + csid => l_csid, + csfrm => l_csfrm, + attr_elt_type => l_attr_elt_type, + aname => l_aname); + + l_result.extend; + l_result(l_result.last) := ut_column_info_rec(l_attribute_typecode, + l_aname, + null, + null, + l_prec, + l_scale, + l_len); + end loop; + return l_result; + end; + + member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) + return anytype is + l_anydata anydata; + l_anytype anytype; + l_typecode pls_integer; + + begin + execute immediate 'declare + l_v ' || a_owner || '.' || + a_type_name || '; + begin + :anydata := anydata.convertobject(l_v); + end;' + using in out l_anydata; + + l_typecode := l_anydata.gettype(l_anytype); + + return l_anytype; + end; + + overriding member procedure init(self in out nocopy ut_column_info_rec, + a_col_type binary_integer, + a_col_name varchar2, + a_col_schema_name varchar2, + a_col_type_name varchar2, + a_col_prec integer, + a_col_scale integer, + a_col_len integer, + a_dbms_sql_desc boolean := false) is + l_anytype anytype; + begin + self.column_prec := a_col_prec; + self.column_len := a_col_len; + self.column_scale := a_col_scale; + self.xml_valid_name := '"'||a_col_name||'"'; + self.column_name := a_col_name; + self.column_type := a_col_type_name; + self.column_schema := a_col_schema_name; + self.is_sql_diffable := 0; + self.is_collection := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_collection(a_col_schema_name,a_col_type_name)); + self.is_user_defined := 1; + + l_anytype := get_user_defined_type(a_col_schema_name, a_col_type_name); + self.nested_details := get_anytype_attributes_info(l_anytype); + end; + + constructor function ut_column_info_rec(self in out nocopy ut_column_info_rec, + a_col_type binary_integer, + a_col_name varchar2, + a_col_schema_name varchar2, + a_col_type_name varchar2, + a_col_prec integer, + a_col_scale integer, + a_col_len integer, + a_dbms_sql_desc boolean := false) + return self as result is + begin + if a_col_type = dbms_sql.user_defined_type then + self.init(a_col_type, a_col_name, a_col_schema_name, a_col_type_name,a_col_prec,a_col_scale,a_col_len); + else + (self as ut_column_info).init(a_col_type, + a_col_name, + a_col_schema_name, + a_col_type_name,a_col_prec,a_col_scale,a_col_len, + a_dbms_sql_desc); + end if; + return; + end; +end; +/ diff --git a/source/expectations/data_values/ut_column_info_rec.tps b/source/expectations/data_values/ut_column_info_rec.tps new file mode 100644 index 000000000..eeb1b93a1 --- /dev/null +++ b/source/expectations/data_values/ut_column_info_rec.tps @@ -0,0 +1,28 @@ +create or replace type ut_column_info_rec under ut_column_info +( + nested_details ut_column_info_tab, + member function get_anytype_attributes_info(a_anytype anytype) + return ut_column_info_tab, + member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) + return anytype, + overriding member procedure init(self in out nocopy ut_column_info_rec, + a_col_type binary_integer, + a_col_name varchar2, + a_col_schema_name varchar2, + a_col_type_name varchar2, + a_col_prec integer, + a_col_scale integer, + a_col_len integer, + a_dbms_sql_desc boolean := false), + constructor function ut_column_info_rec(self in out nocopy ut_column_info_rec, + a_col_type binary_integer, + a_col_name varchar2, + a_col_schema_name varchar2, + a_col_type_name varchar2, + a_col_prec integer, + a_col_scale integer, + a_col_len integer, + a_dbms_sql_desc boolean := false) + return self as result +) +/ diff --git a/source/expectations/data_values/ut_column_info_tab.tps b/source/expectations/data_values/ut_column_info_tab.tps new file mode 100644 index 000000000..27dc44a93 --- /dev/null +++ b/source/expectations/data_values/ut_column_info_tab.tps @@ -0,0 +1,2 @@ +CREATE OR REPLACE TYPE ut_column_info_tab FORCE AS TABLE OF ut_column_info; +/ diff --git a/source/expectations/data_values/ut_cursor_info.tpb b/source/expectations/data_values/ut_cursor_info.tpb new file mode 100644 index 000000000..34e5946cc --- /dev/null +++ b/source/expectations/data_values/ut_cursor_info.tpb @@ -0,0 +1,31 @@ +create or replace type body ut_cursor_info as + constructor function ut_cursor_info(self in out nocopy ut_cursor_info, + a_cursor in out nocopy sys_refcursor) + return self as result is + l_cursor_number integer; + l_columns_count pls_integer; + l_columns_desc dbms_sql.desc_tab3; + begin + self.cursor_info := ut_column_info_tab(); + l_cursor_number := dbms_sql.to_cursor_number(a_cursor); + dbms_sql.describe_columns3(l_cursor_number, + l_columns_count, + l_columns_desc); + a_cursor := dbms_sql.to_refcursor(l_cursor_number); + + for i in 1 .. l_columns_count loop + self.cursor_info.extend; + self.cursor_info(cursor_info.last) := ut_column_info_rec(l_columns_desc(i).col_type, + l_columns_desc(i).col_name, + l_columns_desc(i).col_schema_name, + l_columns_desc(i).col_type_name, + l_columns_desc(i).col_precision, + l_columns_desc(i).col_scale, + l_columns_desc(i).col_name_len, + true); + end loop; + + return; + end ut_cursor_info; +end; +/ diff --git a/source/expectations/data_values/ut_cursor_info.tps b/source/expectations/data_values/ut_cursor_info.tps new file mode 100644 index 000000000..d373ef9a0 --- /dev/null +++ b/source/expectations/data_values/ut_cursor_info.tps @@ -0,0 +1,7 @@ +create or replace type ut_cursor_info force authid current_user as object +( + cursor_info ut_column_info_tab, + constructor function ut_cursor_info(self in out nocopy ut_cursor_info,a_cursor in out nocopy sys_refcursor) + return self as result +) +/ From 2b9d4f385b3a0e51a752bf7e67c9269c01f6889a Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 15 Nov 2018 12:16:09 +0000 Subject: [PATCH 50/83] Capture cursor info and filter it out --- .../data_values/ut_compound_data_helper.pkb | 131 +++++++++++++++++- .../data_values/ut_compound_data_helper.pks | 3 + .../data_values/ut_compound_data_tmp.sql | 3 +- .../ut_curr_usr_compound_helper.pkb | 23 ++- .../ut_curr_usr_compound_helper.pks | 6 +- .../data_values/ut_data_value_refcursor.tpb | 14 +- .../data_values/ut_data_value_refcursor.tps | 8 +- source/expectations/matchers/ut_equal.tpb | 6 +- 8 files changed, 177 insertions(+), 17 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index c75543ef3..bb0b8c1a5 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -18,6 +18,7 @@ create or replace package body ut_compound_data_helper is g_user_defined_type pls_integer := dbms_sql.user_defined_type; g_diff_count integer; + g_filter_tab ut_varchar2_list; function get_column_info_xml(a_column_details ut_key_anyval_pair) return xmltype is l_result varchar2(4000); @@ -620,7 +621,7 @@ create or replace package body ut_compound_data_helper is begin dbms_lob.createtemporary(l_compare_sql, true); - + --TODO: Resolve issues with collection and nested tables, can we extract by internal column name if defined e.g. xml of colval.id.getclobval() --TODO: Comment better all pieces l_column_filter := get_columns_row_filter(a_exclude_xpath, a_include_xpath); @@ -717,7 +718,7 @@ create or replace package body ut_compound_data_helper is l_temp_string := ' (a.data_id is null or e.data_id is null) '; end if; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - + return l_compare_sql; end; @@ -748,5 +749,129 @@ create or replace package body ut_compound_data_helper is return g_diff_count; end; -end; + function populate_filter_columns (a_column_string in varchar2, a_column_info ut_column_info_tab) return ut_column_info_rec is + l_result ut_column_info_rec; + l_column_from_string varchar2(32767); + l_rest_of_path varchar2(32767); + begin + --check if string has a path + l_column_from_string := regexp_substr(a_column_string,'^([^\/]*)?\/?(.*)',1,1,null,1); + for col in 1..a_column_info.count loop + if l_column_from_string = a_column_info(col).column_name then + if a_column_string like '%/%' then + l_rest_of_path := regexp_substr(a_column_string,'^([^\/]*)?\/(.*)',1,1,null,2); + l_result := treat(a_column_info(col) as ut_column_info_rec); + l_result.nested_details := ut_column_info_tab(); + l_result.nested_details.extend; + l_result.nested_details(l_result.nested_details.last) := populate_filter_columns (l_rest_of_path,treat(a_column_info(col) as ut_column_info_rec).nested_details); + else + l_result := treat(a_column_info(col) as ut_column_info_rec); + end if; + end if; + end loop; + return l_result; + end; + + function get_child(a_parent in varchar2 default null) return ut_varchar2_list is + l_out_tab ut_varchar2_list := ut_varchar2_list(); + cursor c_child(cp_parent in varchar2) is + with sorted as + (select r_num, + regexp_substr(t.column_value, '[^/]+', 1, commas.column_value) as colval, + commas.column_value lev + from (select row_number() over(order by 1) r_num, + column_value + from ((table(g_filter_tab)))) t, + table(cast(multiset + (select level + from dual + connect by level <= + length(regexp_replace(t.column_value, + '[^/]+')) + 1) as + sys.odcinumberlist)) commas + order by r_num, + lev), + hier as + (select r_num, + lev, + colval, + lag(colval, 1) over(partition by r_num order by lev) parent + from sorted) + select distinct colval + from hier + where nvl(parent, 1) = nvl(cp_parent, 1); + + begin + open c_child(a_parent); + fetch c_child bulk collect + into l_out_tab; + close c_child; + return l_out_tab; + end; + + function exc_inc_cursors_columns(a_column_info_tab ut_column_info_tab,a_current_list ut_varchar2_list) + return ut_column_info_tab is + l_result ut_column_info_tab := ut_column_info_tab(); + l_record ut_column_info_rec; + l_index integer := 1; + begin + --TODO : Optimize search using while or exists operator ? + for lst in 1..a_current_list.count loop + for i in 1..a_column_info_tab.count loop + if a_current_list(lst) = a_column_info_tab(i).column_name then + l_result.extend; + if a_column_info_tab(i) is of (ut_column_info_rec) then + l_record := treat(a_column_info_tab(i) as ut_column_info_rec); + l_record.nested_details := exc_inc_cursors_columns(treat(a_column_info_tab(i) as ut_column_info_rec).nested_details,get_child(a_column_info_tab(i).column_name)); + end if; + l_result(l_result.last) := l_record; + end if; + end loop; + end loop; + return l_result; + end; + + function inc_exc_columns_from_cursor (a_cursor_info ut_column_info_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) + return ut_column_info_tab is + l_filtered_set ut_varchar2_list := ut_varchar2_list(); + l_result ut_column_info_tab := ut_column_info_tab(); + begin + g_filter_tab := ut_varchar2_list(); + + -- if include and exclude is not null its columns from include minus exclude + -- If inlcude is not null and exclude is null cursor will have only include + -- If exclude is not null and include is null cursor will have all except exclude + + if a_include_xpath.count > 0 and a_exclude_xpath.count > 0 then + select col_names bulk collect into l_filtered_set + from( + select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + from table(a_include_xpath) + minus + select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + from table(a_exclude_xpath) + ); + elsif a_include_xpath.count > 0 and a_exclude_xpath.count = 0 then + select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + bulk collect into l_filtered_set + from table(a_include_xpath); + elsif a_include_xpath.count = 0 and a_exclude_xpath.count > 0 then + select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + bulk collect into l_filtered_set + from table(a_exclude_xpath); + elsif a_cursor_info is not null then + l_result:= a_cursor_info; + else + l_result := ut_column_info_tab(); + end if; + + g_filter_tab := l_filtered_set; + if g_filter_tab.count <> 0 then + l_result := exc_inc_cursors_columns(a_cursor_info,get_child()); + end if; + + return l_result; + end; + +end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 046191aa1..4c844774d 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -102,5 +102,8 @@ create or replace package ut_compound_data_helper authid definer is function get_rows_diff_count return integer; + function inc_exc_columns_from_cursor (a_cursor_info ut_column_info_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) + return ut_column_info_tab; + end; / diff --git a/source/expectations/data_values/ut_compound_data_tmp.sql b/source/expectations/data_values/ut_compound_data_tmp.sql index 7beb1e9cd..0fb5f9544 100644 --- a/source/expectations/data_values/ut_compound_data_tmp.sql +++ b/source/expectations/data_values/ut_compound_data_tmp.sql @@ -19,4 +19,5 @@ create global temporary table ut_compound_data_tmp( pk_hash raw(128), duplicate_no integer, constraint ut_cmp_data_tmp_hash_pk unique (data_id, item_no, duplicate_no) -) on commit preserve rows xmltype column item_data store as binary xml; \ No newline at end of file +) on commit preserve rows; +--xmltype column item_data store as binary xml; \ No newline at end of file diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb index 0cf12f633..15f764062 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb @@ -34,12 +34,7 @@ create or replace package body ut_curr_usr_compound_helper is return ut_utils.boolean_to_int(is_sql_compare_allowed(a_type_name)); end; - function get_column_type(a_desc_rec dbms_sql.desc_rec3, a_desc_user_types boolean := false) return ut_key_anyval_pair is - l_data ut_data_value; - l_result ut_key_anyval_pair; - l_data_type varchar2(500) := 'unknown datatype'; - - function is_collection (a_owner varchar2,a_type_name varchar2) return boolean is + function is_collection (a_owner varchar2,a_type_name varchar2) return boolean is l_type_view varchar2(200) := ut_metadata.get_dba_view('dba_types'); l_typecode varchar2(100); begin @@ -48,7 +43,16 @@ create or replace package body ut_curr_usr_compound_helper is into l_typecode using a_owner,a_type_name; return l_typecode = 'COLLECTION'; + exception + when no_data_found then + return false; end; + + function get_column_type(a_desc_rec dbms_sql.desc_rec3, a_desc_user_types boolean := false) return ut_key_anyval_pair is + l_data ut_data_value; + l_result ut_key_anyval_pair; + l_data_type varchar2(500) := 'unknown datatype'; + --TODO: Review the types in and resolving begin @@ -241,6 +245,11 @@ create or replace package body ut_curr_usr_compound_helper is return l_result ; end; + function get_column_type(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is + begin + return case when not a_dbms_sql_desc then g_anytype_name_map(a_type_code) else g_type_name_map(a_type_code) end; + end; + begin g_anytype_name_map(dbms_types.typecode_date) := 'DATE'; g_anytype_name_map(dbms_types.typecode_number) := 'NUMBER'; @@ -262,7 +271,7 @@ create or replace package body ut_curr_usr_compound_helper is g_anytype_name_map(dbms_types.typecode_varray) := 'VARRRAY'; g_anytype_name_map(dbms_types.typecode_table) := 'TABLE'; g_anytype_name_map(dbms_types.typecode_namedcollection) := 'NAMEDCOLLECTION'; - + g_anytype_collection_name(dbms_types.typecode_varray) := 'VARRRAY'; g_anytype_collection_name(dbms_types.typecode_table) := 'TABLE'; g_anytype_collection_name(dbms_types.typecode_namedcollection) := 'NAMEDCOLLECTION'; diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pks b/source/expectations/data_values/ut_curr_usr_compound_helper.pks index b4230a29d..46404b93c 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pks +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pks @@ -3,7 +3,9 @@ create or replace package ut_curr_usr_compound_helper authid current_user is function is_sql_compare_allowed(a_type_name varchar2) return boolean; function is_sql_compare_int(a_type_name varchar2) return integer; - + + function is_collection (a_owner varchar2,a_type_name varchar2) return boolean; + procedure get_columns_info( a_cursor in out nocopy sys_refcursor, a_columns_info out nocopy xmltype, @@ -15,5 +17,7 @@ create or replace package ut_curr_usr_compound_helper authid current_user is function extract_min_col_info(a_full_col_info xmltype) return xmltype; + function get_column_type(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2; + end; / diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 42b65ecf2..5e4d2a5cb 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -48,6 +48,8 @@ create or replace type body ut_data_value_refcursor as self.elements_count := 0; self.columns_info := ut_curr_usr_compound_helper.extract_min_col_info(self.col_info_desc); + self.cursor_col_info := ut_cursor_info(l_cursor); + -- We use DBMS_XMLGEN in order to: -- 1) be able to process data in bulks (set of rows) -- 2) be able to influence the ROWSET/ROW tags @@ -99,7 +101,7 @@ create or replace type body ut_data_value_refcursor as dbms_xmlgen.closeContext(l_ctx); raise; end; - + overriding member function to_string return varchar2 is l_result clob; l_result_string varchar2(32767); @@ -236,7 +238,7 @@ create or replace type body ut_data_value_refcursor as if not a_other is of (ut_data_value_refcursor) then raise value_error; end if; - + l_other := treat(a_other as ut_data_value_refcursor); --if we join by key and key is missing fail and report error @@ -265,6 +267,14 @@ create or replace type body ut_data_value_refcursor as return self.elements_count = 0; end; + member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor is + l_result ut_data_value_refcursor := self; + begin + if l_result.cursor_col_info.cursor_info is not null then + l_result.cursor_col_info.cursor_info := ut_compound_data_helper.inc_exc_columns_from_cursor(l_result.cursor_col_info.cursor_info,a_exclude_xpath,a_include_xpath); + end if; + return l_result; + end; end; / diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 29ee3b702..fa6e41483 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -44,12 +44,18 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( */ key_info xmltype, + /* + *columns info + */ + cursor_col_info ut_cursor_info, + constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) return self as result, member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), overriding member function to_string return varchar2, overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, overriding member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false) return integer, - overriding member function is_empty return boolean + overriding member function is_empty return boolean, + member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor ) / diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index 611b1cd1c..8e857ad80 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -25,7 +25,7 @@ create or replace type body ut_equal as self.exclude_list := ut_varchar2_list(); self.join_columns := ut_varchar2_list(); end; - + member function equal_with_nulls(a_assert_result boolean, a_actual ut_data_value) return boolean is begin ut_utils.debug_log('ut_equal.equal_with_nulls :' || ut_utils.to_test_result(a_assert_result) || ':'); @@ -228,12 +228,14 @@ create or replace type body ut_equal as overriding member function run_matcher(self in out nocopy ut_equal, a_actual ut_data_value) return boolean is l_result boolean; + l_actual ut_data_value; begin if self.expected.data_type = a_actual.data_type then if self.expected is of (ut_data_value_anydata) then l_result := 0 = treat(self.expected as ut_data_value_anydata).compare_implementation(a_actual, get_exclude_xpath(), get_include_xpath()); elsif self.expected is of (ut_data_value_refcursor) then - l_result := 0 = treat(self.expected as ut_data_value_refcursor).compare_implementation(a_actual, get_exclude_xpath(), get_include_xpath(), get_join_by_xpath(), get_unordered()); + l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); + l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(a_actual, get_exclude_xpath(), get_include_xpath(), get_join_by_xpath(), get_unordered()); else l_result := equal_with_nulls((self.expected = a_actual), a_actual); end if; From fc905ace49a6146fe1ed3da23d9f33871afdeca5 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Fri, 16 Nov 2018 23:30:15 +0000 Subject: [PATCH 51/83] Saving progress --- .../data_values/ut_column_info.tpb | 16 +- .../data_values/ut_column_info.tps | 6 +- .../data_values/ut_column_info_rec.tpb | 36 +- .../data_values/ut_column_info_rec.tps | 13 +- .../data_values/ut_compound_data_helper.pkb | 387 +++++++++--------- .../data_values/ut_compound_data_helper.pks | 6 +- .../data_values/ut_compound_data_value.tpb | 6 +- .../data_values/ut_compound_data_value.tps | 3 +- .../data_values/ut_cursor_info.tpb | 2 +- .../data_values/ut_data_value_refcursor.tpb | 5 +- .../data_values/ut_data_value_refcursor.tps | 3 +- source/expectations/matchers/ut_equal.tpb | 51 ++- source/expectations/matchers/ut_equal.tps | 6 + source/expectations/matchers/ut_include.tpb | 7 +- 14 files changed, 298 insertions(+), 249 deletions(-) diff --git a/source/expectations/data_values/ut_column_info.tpb b/source/expectations/data_values/ut_column_info.tpb index 5e913bf31..3bd99f15d 100644 --- a/source/expectations/data_values/ut_column_info.tpb +++ b/source/expectations/data_values/ut_column_info.tpb @@ -11,15 +11,21 @@ create or replace type body ut_column_info as a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_len integer, - a_dbms_sql_desc boolean := false) is + a_col_max_len integer, + a_dbms_sql_desc boolean := false, + a_parent_name varchar2 := null) is begin self.is_user_defined := 0; self.column_prec := a_col_prec; - self.column_len := a_col_len; + self.column_len := a_col_max_len; self.column_scale := a_col_scale; - self.xml_valid_name := '"'||a_col_name||'"'; - self.column_name := a_col_name; + self.column_name := TRIM( BOTH '''' FROM a_col_name); + self.xml_valid_name := '"'||self.column_name||'"'; + self.hashed_name := case when a_parent_name is not null then + ut_compound_data_helper.get_hash(utl_raw.cast_to_raw(a_parent_name||self.column_name)) + else + null + end; self.column_type := get_data_type(a_col_type,a_dbms_sql_desc); self.column_schema := a_col_schema_name; self.is_sql_diffable := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)); diff --git a/source/expectations/data_values/ut_column_info.tps b/source/expectations/data_values/ut_column_info.tps index 331ab3d2e..27639771f 100644 --- a/source/expectations/data_values/ut_column_info.tps +++ b/source/expectations/data_values/ut_column_info.tps @@ -1,6 +1,7 @@ create or replace type ut_column_info force authid current_user as object ( xml_valid_name varchar2(100), + hashed_name raw(30), column_name varchar2(100), column_type varchar2(100), column_schema varchar2(100), @@ -18,8 +19,9 @@ create or replace type ut_column_info force authid current_user as object a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_len integer, - a_dbms_sql_desc boolean := false) + a_col_max_len integer, + a_dbms_sql_desc boolean := false, + a_parent_name varchar2 := null) ) not final not instantiable / diff --git a/source/expectations/data_values/ut_column_info_rec.tpb b/source/expectations/data_values/ut_column_info_rec.tpb index 19d6ab13a..efdbcced1 100644 --- a/source/expectations/data_values/ut_column_info_rec.tpb +++ b/source/expectations/data_values/ut_column_info_rec.tpb @@ -1,6 +1,6 @@ create or replace type body ut_column_info_rec as - member function get_anytype_attributes_info(a_anytype anytype) + member function get_anytype_attributes_info(a_anytype anytype, a_col_name varchar2) return ut_column_info_tab is l_result ut_column_info_tab := ut_column_info_tab(); l_attribute_typecode pls_integer; @@ -54,7 +54,9 @@ create or replace type body ut_column_info_rec as null, l_prec, l_scale, - l_len); + l_len, + false, + a_col_name); end loop; return l_result; end; @@ -86,15 +88,21 @@ create or replace type body ut_column_info_rec as a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_len integer, - a_dbms_sql_desc boolean := false) is + a_col_max_len integer, + a_dbms_sql_desc boolean := false, + a_parent_name varchar2) is l_anytype anytype; begin self.column_prec := a_col_prec; - self.column_len := a_col_len; + self.column_len := a_col_max_len; self.column_scale := a_col_scale; - self.xml_valid_name := '"'||a_col_name||'"'; - self.column_name := a_col_name; + self.column_name := TRIM(BOTH '''' FROM a_col_name); + self.xml_valid_name := '"'||self.column_name||'"'; + self.hashed_name := case when a_parent_name is not null then + ut_compound_data_helper.get_hash(utl_raw.cast_to_raw(a_parent_name||self.column_name)) + else + null + end; self.column_type := a_col_type_name; self.column_schema := a_col_schema_name; self.is_sql_diffable := 0; @@ -102,7 +110,7 @@ create or replace type body ut_column_info_rec as self.is_user_defined := 1; l_anytype := get_user_defined_type(a_col_schema_name, a_col_type_name); - self.nested_details := get_anytype_attributes_info(l_anytype); + self.nested_details := get_anytype_attributes_info(l_anytype, self.column_name); end; constructor function ut_column_info_rec(self in out nocopy ut_column_info_rec, @@ -112,18 +120,20 @@ create or replace type body ut_column_info_rec as a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_len integer, - a_dbms_sql_desc boolean := false) + a_col_max_len integer, + a_dbms_sql_desc boolean := false, + a_parent_name varchar2 := null) return self as result is begin if a_col_type = dbms_sql.user_defined_type then - self.init(a_col_type, a_col_name, a_col_schema_name, a_col_type_name,a_col_prec,a_col_scale,a_col_len); + self.init(a_col_type, a_col_name, a_col_schema_name, a_col_type_name,a_col_prec,a_col_scale,a_col_max_len); else (self as ut_column_info).init(a_col_type, a_col_name, a_col_schema_name, - a_col_type_name,a_col_prec,a_col_scale,a_col_len, - a_dbms_sql_desc); + a_col_type_name,a_col_prec,a_col_scale,a_col_max_len, + a_dbms_sql_desc, + a_parent_name); end if; return; end; diff --git a/source/expectations/data_values/ut_column_info_rec.tps b/source/expectations/data_values/ut_column_info_rec.tps index eeb1b93a1..0059bd08d 100644 --- a/source/expectations/data_values/ut_column_info_rec.tps +++ b/source/expectations/data_values/ut_column_info_rec.tps @@ -1,7 +1,8 @@ create or replace type ut_column_info_rec under ut_column_info ( nested_details ut_column_info_tab, - member function get_anytype_attributes_info(a_anytype anytype) + parent_name varchar2(100), + member function get_anytype_attributes_info(a_anytype anytype, a_col_name varchar2) return ut_column_info_tab, member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return anytype, @@ -12,8 +13,9 @@ create or replace type ut_column_info_rec under ut_column_info a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_len integer, - a_dbms_sql_desc boolean := false), + a_col_max_len integer, + a_dbms_sql_desc boolean := false, + a_parent_name varchar2 := null), constructor function ut_column_info_rec(self in out nocopy ut_column_info_rec, a_col_type binary_integer, a_col_name varchar2, @@ -21,8 +23,9 @@ create or replace type ut_column_info_rec under ut_column_info a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_len integer, - a_dbms_sql_desc boolean := false) + a_col_max_len integer, + a_dbms_sql_desc boolean := false, + a_parent_name varchar2 := null) return self as result ) / diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index bb0b8c1a5..613b97bb8 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -424,179 +424,147 @@ create or replace package body ut_compound_data_helper is return l_no_missing_keys; end; - - function generate_select_stmt(a_column_info ut_varchar2_list,a_xml_column_info xmltype) return clob is - l_sql_stmt clob; - l_col_type varchar2(4000); - l_alias varchar2(10) := 'ucd.'; - l_col_syntax varchar2(4000); - l_ut_owner varchar2(250) := ut_utils.ut_owner; - begin - for i in (select /*+ CARDINALITY(xt 100) */ - distinct - t.column_value, - xt.is_sql_diff, - xt.type - from - (select a_xml_column_info item_data from dual) x, - xmltable( - '/ROW/*' - passing x.item_data - columns - name varchar2(4000) PATH '@xml_valid_name', - type varchar2(4000) PATH '/', - is_sql_diff varchar2(4000) PATH '@sql_diffable' - ) xt, - table(a_column_info) t - where '"'||xt.name||'"' = t.column_value) + + procedure generate_not_equal_stmt(a_data_info ut_column_info, a_pk_table ut_varchar2_list, a_not_equal_stmt in out nocopy clob) is + l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); + l_index integer; + l_sql_stmt varchar2(32767); + l_exists boolean := false; + begin + l_index := l_pk_tab.first; + if l_pk_tab.count > 0 then + loop + if a_data_info.column_name = l_pk_tab(l_index) then + l_exists := true; + end if; + exit when l_index = l_pk_tab.count or (a_data_info.column_name = l_pk_tab(l_index)); + l_index := a_pk_table.next(l_index); + end loop; + end if; + + if not(l_exists) then + l_sql_stmt := l_sql_stmt || case when a_not_equal_stmt is null then null else ' or ' end + ||' (decode(a.'||a_data_info.xml_valid_name||','||' e.'||a_data_info.xml_valid_name||',1,0) = 0)'; + ut_utils.append_to_clob(a_not_equal_stmt,l_sql_stmt); + end if; + end; + + procedure generate_join_by_stmt(a_data_info ut_column_info, a_pk_table ut_varchar2_list, a_join_by_stmt in out nocopy clob) is + l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); + l_index integer ; + l_sql_stmt varchar2(32767); + begin + if l_pk_tab.count <> 0 then + l_index:= l_pk_tab.first; loop - if i.is_sql_diff = 0 then - l_col_syntax := l_ut_owner ||'.ut_compound_data_helper.get_hash('||l_alias||i.column_value||'.getClobVal()) as '||i.column_value ; - else - l_col_syntax := l_alias||i.column_value||' as '|| i.column_value; + if a_data_info.column_name = a_pk_table(l_index) then + l_sql_stmt := l_sql_stmt || case when a_join_by_stmt is null then null else ' and ' end; + if a_data_info.is_sql_diffable = 0 then + --TODO : Non diffable is more complex as to hash we need to know how to cast it to raw or clob ? + /*l_sql_stmt := l_ut_owner ||'.ut_compound_data_helper.get_hash( a.'||a_data_info.xml_valid_name||') = ' + ||l_ut_owner ||'.ut_compound_data_helper.get_hash( e.'||a_data_info.xml_valid_name||')';*/ + l_sql_stmt := l_sql_stmt ||' a.'||a_data_info.xml_valid_name||q'[ = ]'||' e.'||a_data_info.xml_valid_name; + elsif a_data_info.is_sql_diffable = 1 then + l_sql_stmt := l_sql_stmt ||' a.'||a_data_info.xml_valid_name||q'[ = ]'||' e.'||a_data_info.xml_valid_name; + end if; end if; - - l_sql_stmt := l_sql_stmt ||','||l_col_syntax; + exit when (a_data_info.column_name = a_pk_table(l_index)) or l_index = a_pk_table.count; + l_index := a_pk_table.next(l_index); end loop; - return l_sql_stmt; + ut_utils.append_to_clob(a_join_by_stmt,l_sql_stmt); + end if; end; - function generate_partition_stmt(a_column_info ut_varchar2_list) return clob is - l_sql_stmt clob; - l_alias varchar2(10) := 'ucd.'; + procedure generate_equal_sql(a_data_info ut_column_info,a_equal_stmt in out nocopy clob) is + l_sql_stmt varchar2(32767); + begin + l_sql_stmt := case when a_equal_stmt is null then null else ' and ' end ||' a.'||a_data_info.xml_valid_name||q'[ = ]'||' e.'||a_data_info.xml_valid_name; + ut_utils.append_to_clob(a_equal_stmt,l_sql_stmt); + end; + procedure generate_partition_stmt(a_data_info ut_column_info,a_partition_stmt in out nocopy clob) is + l_alias varchar2(10) := 'ucd.'; begin - if a_column_info.count > 0 or a_column_info is null then - for i in 1..a_column_info.count - loop - l_sql_stmt := l_sql_stmt || case - when l_sql_stmt is null then - null - else ',' - end||l_alias||a_column_info(i); - end loop; - l_sql_stmt := ', row_number() over (partition by '|| l_sql_stmt || ' order by '||l_sql_stmt||' ) dup_no '; - else - l_sql_stmt := ', 1 dup_no '; - end if; - return l_sql_stmt; - end; - - function generate_xmltab_stmt (a_column_info ut_varchar2_list,a_xml_column_info xmltype) return clob is + ut_utils.append_to_clob(a_partition_stmt,case when a_partition_stmt is null then null else ',' end||l_alias||a_data_info.xml_valid_name); + end; + + procedure generate_select_stmt(a_data_info ut_column_info,a_sql_stmt in out nocopy clob) is l_sql_stmt clob; + l_alias varchar2(10) := 'ucd.'; + l_col_syntax varchar2(4000); + l_ut_owner varchar2(250) := ut_utils.ut_owner; + begin + if a_data_info.is_sql_diffable = 0 then + l_col_syntax := l_ut_owner ||'.ut_compound_data_helper.get_hash('||l_alias||a_data_info.xml_valid_name||'.getClobVal()) as '||a_data_info.xml_valid_name ; + else + l_col_syntax := l_alias||a_data_info.xml_valid_name||' as '|| a_data_info.xml_valid_name; + end if; + ut_utils.append_to_clob(a_sql_stmt,','||l_col_syntax); + end; + + procedure generate_xmltab_stmt(a_data_info ut_column_info,a_sql_stmt in out nocopy clob) is + l_sql_stmt varchar2(32767); l_col_type varchar2(4000); begin - for i in (select /*+ CARDINALITY(xt 100) */ - distinct - t.column_value, - xt.is_sql_diff, - xt.type - from - (select a_xml_column_info item_data from dual) x, - xmltable( - '/ROW/*' - passing x.item_data - columns - name varchar2(4000) PATH '@xml_valid_name', - type varchar2(4000) PATH '/', - is_sql_diff varchar2(4000) PATH '@sql_diffable' - ) xt, - table(a_column_info) t - where '"'||xt.name||'"' = t.column_value) - loop - if i.is_sql_diff = 0 then - l_col_type := 'XMLTYPE'; - elsif i.is_sql_diff = 1 and (i.type IN ('CHAR','VARCHAR2','VARCHAR')) then - l_col_type := 'VARCHAR2(4000)'; - elsif i.is_sql_diff = 1 and i.type = 'DATE' then - l_col_type := 'TIMESTAMP'; - else - l_col_type := i.type; - end if; - - l_sql_stmt := l_sql_stmt||i.column_value||' '||l_col_type||q'[ PATH ']'||TRIM(BOTH '"' FROM i.column_value)||q'[',]'; - end loop; - return l_sql_stmt; + if a_data_info.is_sql_diffable = 0 then + l_col_type := 'XMLTYPE'; + elsif a_data_info.is_sql_diffable = 1 and a_data_info.column_type = 'DATE' then + l_col_type := 'TIMESTAMP'; + else + l_col_type := a_data_info.column_type||'('||a_data_info.column_len||')'; + end if; + l_sql_stmt := ' '||a_data_info.xml_valid_name||' '||l_col_type||q'[ PATH ']'||a_data_info.column_name||q'[',]'; + ut_utils.append_to_clob(a_sql_stmt, l_sql_stmt); end; - - function generate_equal_sql (a_column_info ut_varchar2_list) return clob is - l_sql_stmt clob; + + procedure gen_sql_pieces_out_of_cursor(a_data_info ut_data_value_refcursor,a_pk_table ut_varchar2_list, a_xml_stmt out nocopy clob, + a_select_stmt out nocopy clob ,a_partition_stmt out nocopy clob, a_equal_stmt out nocopy clob, a_join_by_stmt out nocopy clob, + a_not_equal_stmt out nocopy clob) is + l_cursor_info ut_column_info_tab := a_data_info.cursor_col_info.cursor_info; + l_partition_tmp clob; begin - for i in 1..a_column_info.count loop - l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||a_column_info(i)||q'[ = ]'||' e.'||a_column_info(i); - end loop; - return l_sql_stmt; - end; - - function generate_join_by_on_stmt (a_join_by_xpath_tab ut_varchar2_list, a_columns_info xmltype, a_join_by_xpath in varchar2) return clob is - l_sql_stmt clob; - l_non_diff_var varchar2(32767); - l_ut_owner varchar2(250) := ut_utils.ut_owner; - begin - for i in (select /*+ CARDINALITY(xt 100) */ - distinct - t.column_value, - xt.is_sql_diff - from - (select a_columns_info item_data from dual) x, - xmltable( - '/ROW/*' - passing x.item_data - columns - name varchar2(4000) PATH '@xml_valid_name', - is_sql_diff varchar2(4000) PATH '@sql_diffable' - ) xt, - table(a_join_by_xpath_tab) t - where '"'||xt.name||'"' = t.column_value) - loop - - if i.is_sql_diff = 0 then - l_non_diff_var := l_ut_owner ||'.ut_compound_data_helper.get_hash((extract( a.'||i.column_value||', '||a_join_by_xpath||')).getclobval()) = ' - ||l_ut_owner ||'.ut_compound_data_helper.get_hash((extract( e.'||i.column_value||', '||a_join_by_xpath||')).getclobval())'; - l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.column_value||q'[ = ]'||' e.'||i.column_value; - elsif i.is_sql_diff = 1 then - l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' and ' end ||' a.'||i.column_value||q'[ = ]'||' e.'||i.column_value; - end if; - - end loop; - - return l_sql_stmt; + if l_cursor_info is not null then + --Parition by piece + ut_utils.append_to_clob(a_partition_stmt,', row_number() over (partition by '); + --TODO : Handle nested objects... + for i in 1..l_cursor_info.count loop + --Get XMLTABLE column list + generate_xmltab_stmt(l_cursor_info(i),a_xml_stmt); + --Get Select statment list of columns + generate_select_stmt(l_cursor_info(i),a_select_stmt); + --Get columns by which we partition + generate_partition_stmt(l_cursor_info(i),l_partition_tmp); + --Get equal statement + generate_equal_sql(l_cursor_info(i),a_equal_stmt); + --Generate join by stmt + generate_join_by_stmt(l_cursor_info(i),a_pk_table,a_join_by_stmt); + --Generate not equal stmt + generate_not_equal_stmt(l_cursor_info(i),a_pk_table,a_not_equal_stmt); + end loop; + --Finish parition by + ut_utils.append_to_clob(a_partition_stmt,l_partition_tmp||' order by '||l_partition_tmp||' ) dup_no '); + else + --Partition by piece when no data + ut_utils.append_to_clob(a_partition_stmt,', 1 dup_no '); + end if; end; - - function generate_not_equal_sql (a_column_info ut_varchar2_list, a_join_by_xpath ut_varchar2_list) return clob is - l_sql_stmt clob; - begin - for i in ( - with xpaths_tab as (select column_value xpath from table(a_join_by_xpath)), - pk_names as (select '"'||REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$')||'"' name - from xpaths_tab) - select /*+ CARDINALITY(xt 100) */ - column_value as name - from table(a_column_info) xt - where not exists (select 1 from pk_names p where lower(p.name) = lower(xt.column_value)) - ) - loop - l_sql_stmt := l_sql_stmt || case when l_sql_stmt is null then null else ' or ' end ||' (decode(a.'||i.name||','||' e.'||i.name||',1,0) = 0)'; - end loop; - return l_sql_stmt; - end; function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean, - a_unordered boolean) return clob is + a_unordered boolean, a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=null ) return clob is l_compare_sql clob; l_temp_string varchar2(32767); - l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); - l_act_col_tab ut_varchar2_list := ut_varchar2_list(); - l_ut_owner varchar2(250) := ut_utils.ut_owner; l_xmltable_stmt clob; l_where_stmt clob; l_select_stmt clob; l_partition_stmt clob; + l_equal_stmt clob; + l_join_on_stmt clob; + l_not_equal_stmt clob; l_column_filter varchar2(32767); - + function get_filtered_columns_name (a_columns_info in xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2) return ut_varchar2_list is l_columns_info ut_varchar2_list := ut_varchar2_list(); begin @@ -626,14 +594,10 @@ create or replace package body ut_compound_data_helper is --TODO: Comment better all pieces l_column_filter := get_columns_row_filter(a_exclude_xpath, a_include_xpath); - l_act_col_tab := get_filtered_columns_name(a_column_info,a_exclude_xpath,a_include_xpath); - - l_pk_xpath_tabs := get_filtered_columns_name(a_column_info,null,a_join_by_xpath); - - l_xmltable_stmt := generate_xmltab_stmt(l_act_col_tab,a_column_info); - l_select_stmt := generate_select_stmt(l_act_col_tab,a_column_info); - l_partition_stmt := generate_partition_stmt(l_act_col_tab); - + gen_sql_pieces_out_of_cursor(a_other, a_join_by_list, + l_xmltable_stmt, l_select_stmt, l_partition_stmt, l_equal_stmt, + l_join_on_stmt, l_not_equal_stmt); + l_temp_string := 'with exp as ( select ucd.* '; ut_utils.append_to_clob(l_compare_sql, l_temp_string); ut_utils.append_to_clob(l_compare_sql,l_partition_stmt); @@ -689,10 +653,10 @@ create or replace package body ut_compound_data_helper is if a_join_by_xpath is null and a_unordered then -- If no key defined do the join on all columns - ut_utils.append_to_clob(l_compare_sql,generate_equal_sql(l_act_col_tab)); + ut_utils.append_to_clob(l_compare_sql,l_equal_stmt); elsif a_join_by_xpath is not null and a_unordered then -- If key defined do the join or these and where on diffrences - ut_utils.append_to_clob(l_compare_sql,generate_join_by_on_stmt (l_pk_xpath_tabs,a_column_info,a_join_by_xpath)); + ut_utils.append_to_clob(l_compare_sql,l_join_on_stmt); elsif not a_unordered then ut_utils.append_to_clob(l_compare_sql, 'a.item_no = e.item_no ' ); end if; @@ -700,14 +664,12 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql,' ) where '); if (a_join_by_xpath is not null) and (a_unordered) and (not a_is_negated) then - l_where_stmt := generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); - if l_where_stmt is not null then - ut_utils.append_to_clob(l_compare_sql,' ( '||l_where_stmt||' ) or '); + if l_not_equal_stmt is not null then + ut_utils.append_to_clob(l_compare_sql,' ( '||l_not_equal_stmt||' ) or '); end if; elsif not a_unordered then - l_where_stmt := generate_not_equal_sql(l_act_col_tab, l_pk_xpath_tabs); - if l_where_stmt is not null then - ut_utils.append_to_clob(l_compare_sql,' ( '||l_where_stmt||' ) or '); + if l_not_equal_stmt is not null then + ut_utils.append_to_clob(l_compare_sql,' ( '||l_not_equal_stmt||' ) or '); end if; end if; @@ -718,7 +680,8 @@ create or replace package body ut_compound_data_helper is l_temp_string := ' (a.data_id is null or e.data_id is null) '; end if; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - + + --dbms_output.put_line(l_compare_sql); return l_compare_sql; end; @@ -749,29 +712,6 @@ create or replace package body ut_compound_data_helper is return g_diff_count; end; - function populate_filter_columns (a_column_string in varchar2, a_column_info ut_column_info_tab) return ut_column_info_rec is - l_result ut_column_info_rec; - l_column_from_string varchar2(32767); - l_rest_of_path varchar2(32767); - begin - --check if string has a path - l_column_from_string := regexp_substr(a_column_string,'^([^\/]*)?\/?(.*)',1,1,null,1); - for col in 1..a_column_info.count loop - if l_column_from_string = a_column_info(col).column_name then - if a_column_string like '%/%' then - l_rest_of_path := regexp_substr(a_column_string,'^([^\/]*)?\/(.*)',1,1,null,2); - l_result := treat(a_column_info(col) as ut_column_info_rec); - l_result.nested_details := ut_column_info_tab(); - l_result.nested_details.extend; - l_result.nested_details(l_result.nested_details.last) := populate_filter_columns (l_rest_of_path,treat(a_column_info(col) as ut_column_info_rec).nested_details); - else - l_result := treat(a_column_info(col) as ut_column_info_rec); - end if; - end if; - end loop; - return l_result; - end; - function get_child(a_parent in varchar2 default null) return ut_varchar2_list is l_out_tab ut_varchar2_list := ut_varchar2_list(); cursor c_child(cp_parent in varchar2) is @@ -809,39 +749,75 @@ create or replace package body ut_compound_data_helper is return l_out_tab; end; - function exc_inc_cursors_columns(a_column_info_tab ut_column_info_tab,a_current_list ut_varchar2_list) + function inc_cursors_columns(a_column_info_tab ut_column_info_tab,a_current_list ut_varchar2_list) return ut_column_info_tab is l_result ut_column_info_tab := ut_column_info_tab(); l_record ut_column_info_rec; - l_index integer := 1; + l_index integer; begin - --TODO : Optimize search using while or exists operator ? for lst in 1..a_current_list.count loop - for i in 1..a_column_info_tab.count loop - if a_current_list(lst) = a_column_info_tab(i).column_name then + l_index := a_column_info_tab.first; + loop + if a_current_list(lst) = a_column_info_tab(l_index).column_name then l_result.extend; - if a_column_info_tab(i) is of (ut_column_info_rec) then - l_record := treat(a_column_info_tab(i) as ut_column_info_rec); - l_record.nested_details := exc_inc_cursors_columns(treat(a_column_info_tab(i) as ut_column_info_rec).nested_details,get_child(a_column_info_tab(i).column_name)); + l_record := treat(a_column_info_tab(l_index) as ut_column_info_rec); + + if treat(a_column_info_tab(l_index) as ut_column_info_rec).nested_details is not null then + l_record.nested_details := inc_cursors_columns(treat(a_column_info_tab(l_index) as ut_column_info_rec).nested_details,get_child(a_column_info_tab(l_index).column_name)); end if; + l_result(l_result.last) := l_record; end if; + exit when (a_current_list(lst) = a_column_info_tab(l_index).column_name) or (l_index = a_column_info_tab.count); + l_index := a_column_info_tab.next(l_index); end loop; end loop; + + return l_result; + end; + + function exc_cursors_columns(a_column_info_tab ut_column_info_tab,a_current_list ut_varchar2_list) + return ut_column_info_tab is + l_result ut_column_info_tab := ut_column_info_tab(); + l_record ut_column_info_rec; + l_index integer; + l_exists boolean := false; + begin + --TODO : Optimize search using while or exists operator ? + for lst in 1..a_column_info_tab.count loop + l_index := a_current_list.first; + loop + if a_current_list(l_index) = a_column_info_tab(lst).column_name then + l_exists := true; + end if; + exit when (a_current_list(l_index) = a_column_info_tab(lst).column_name) or (l_index = a_current_list.count); + l_index := a_current_list.next(l_index); + end loop; + + if not(l_exists) then + l_result.extend; + l_record := treat(a_column_info_tab(lst) as ut_column_info_rec); + if treat(a_column_info_tab(lst) as ut_column_info_rec).nested_details is not null then + l_record.nested_details := exc_cursors_columns(treat(a_column_info_tab(lst) as ut_column_info_rec).nested_details,get_child(a_column_info_tab(lst).column_name)); + end if; + l_result(l_result.last) := l_record; + end if; + l_exists := false; + end loop; return l_result; end; function inc_exc_columns_from_cursor (a_cursor_info ut_column_info_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_column_info_tab is l_filtered_set ut_varchar2_list := ut_varchar2_list(); - l_result ut_column_info_tab := ut_column_info_tab(); + l_result ut_column_info_tab := ut_column_info_tab(); + l_include boolean; begin g_filter_tab := ut_varchar2_list(); - + -- if include and exclude is not null its columns from include minus exclude -- If inlcude is not null and exclude is null cursor will have only include -- If exclude is not null and include is null cursor will have all except exclude - if a_include_xpath.count > 0 and a_exclude_xpath.count > 0 then select col_names bulk collect into l_filtered_set from( @@ -851,23 +827,28 @@ create or replace package body ut_compound_data_helper is select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names from table(a_exclude_xpath) ); + l_include := true; elsif a_include_xpath.count > 0 and a_exclude_xpath.count = 0 then select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names bulk collect into l_filtered_set from table(a_include_xpath); + l_include := true; elsif a_include_xpath.count = 0 and a_exclude_xpath.count > 0 then select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names bulk collect into l_filtered_set from table(a_exclude_xpath); + l_include := false; elsif a_cursor_info is not null then l_result:= a_cursor_info; else l_result := ut_column_info_tab(); end if; - - g_filter_tab := l_filtered_set; - if g_filter_tab.count <> 0 then - l_result := exc_inc_cursors_columns(a_cursor_info,get_child()); + + g_filter_tab := l_filtered_set; + if l_filtered_set.count <> 0 and l_include then + l_result := inc_cursors_columns(a_cursor_info,get_child()); + elsif l_filtered_set.count <> 0 and not(l_include) then + l_result := exc_cursors_columns(a_cursor_info,get_child()); end if; return l_result; diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 4c844774d..924593c62 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -52,8 +52,8 @@ create or replace package ut_compound_data_helper authid definer is act_data_id raw(32), exp_item_data xmltype, exp_data_id raw(32), - item_no integer, - dup_no integer + item_no number, + dup_no number ); type t_diff_tab is table of t_diff_rec; @@ -92,7 +92,7 @@ create or replace package ut_compound_data_helper authid definer is function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean, - a_unordered boolean ) return clob; + a_unordered boolean, a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=null ) return clob; procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw); diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 51b2e22cc..9b37dd8ea 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -201,7 +201,8 @@ create or replace type body ut_compound_data_value as end; member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false ) return integer is + a_join_by_xpath varchar2,a_unordered boolean, a_inclusion_compare boolean := false, + a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=null ) return integer is l_diff_id ut_compound_data_helper.t_hash; l_other ut_compound_data_value; @@ -221,7 +222,8 @@ create or replace type body ut_compound_data_value as l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); open l_loop_curs for ut_compound_data_helper.gen_compare_sql(treat(a_other as ut_data_value_refcursor).col_info_desc, a_exclude_xpath, - a_include_xpath, a_join_by_xpath, a_inclusion_compare, a_is_negated, a_unordered ) using self.data_id,l_other.data_id; + a_include_xpath, a_join_by_xpath, a_inclusion_compare, a_is_negated, a_unordered, + treat(a_other as ut_data_value_refcursor), a_join_by_list ) using self.data_id,l_other.data_id; loop fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; exit when l_diff_tab.count = 0; diff --git a/source/expectations/data_values/ut_compound_data_value.tps b/source/expectations/data_values/ut_compound_data_value.tps index 2e76bb8f8..ce14c494e 100644 --- a/source/expectations/data_values/ut_compound_data_value.tps +++ b/source/expectations/data_values/ut_compound_data_value.tps @@ -45,6 +45,7 @@ create or replace type ut_compound_data_value force under ut_data_value( member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return clob, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2) return integer, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2, a_unordered boolean, a_inclusion_compare boolean := false,a_is_negated boolean := false ) return integer + a_join_by_xpath varchar2, a_unordered boolean, a_inclusion_compare boolean := false, + a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=null ) return integer ) not final not instantiable / diff --git a/source/expectations/data_values/ut_cursor_info.tpb b/source/expectations/data_values/ut_cursor_info.tpb index 34e5946cc..819ac704a 100644 --- a/source/expectations/data_values/ut_cursor_info.tpb +++ b/source/expectations/data_values/ut_cursor_info.tpb @@ -21,7 +21,7 @@ create or replace type body ut_cursor_info as l_columns_desc(i).col_type_name, l_columns_desc(i).col_precision, l_columns_desc(i).col_scale, - l_columns_desc(i).col_name_len, + l_columns_desc(i).col_max_len, true); end loop; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 5e4d2a5cb..84552ed4a 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -227,7 +227,8 @@ create or replace type body ut_data_value_refcursor as end; overriding member function compare_implementation (a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false) return integer is + a_unordered boolean, a_inclusion_compare boolean := false, + a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=null) return integer is l_result integer := 0; l_other ut_data_value_refcursor; function is_pk_missing (a_pk_missing_tab ut_compound_data_helper.tt_missing_pk) return integer is @@ -256,7 +257,7 @@ create or replace type body ut_data_value_refcursor as end if; l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, - a_join_by_xpath,a_unordered, a_inclusion_compare, a_is_negated); + a_join_by_xpath,a_unordered, a_inclusion_compare, a_is_negated, a_join_by_list); end if; return l_result; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index fa6e41483..790ddf895 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -54,7 +54,8 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( overriding member function to_string return varchar2, overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, overriding member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false) return integer, + a_unordered boolean, a_inclusion_compare boolean := false, + a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=null) return integer, overriding member function is_empty return boolean, member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor ) diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index 8e857ad80..854b4eef0 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -158,28 +158,44 @@ create or replace type body ut_equal as member function include(a_items varchar2) return ut_equal is l_result ut_equal := self; begin - ut_utils.append_to_list(l_result.include_list, a_items); + l_result.include_list := l_result.include_list multiset union all coalesce(ut_utils.string_to_table(a_items,','),ut_varchar2_list()); + l_result.include_list := l_result.include_list multiset union all coalesce(ut_utils.string_to_table(a_items,'|'),ut_varchar2_list()); return l_result; end; member function include(a_items ut_varchar2_list) return ut_equal is l_result ut_equal := self; - begin - l_result.include_list := l_result.include_list multiset union all coalesce(a_items,ut_varchar2_list()); + l_items ut_varchar2_list := ut_varchar2_list(); + begin + --Split exclude into single expressions so we cater for concat operator like | + for i in 1..a_items.count loop + l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_items(i),'|'),ut_varchar2_list()); + l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_items(i),','),ut_varchar2_list()); + end loop; + l_result.include_list := l_result.include_list multiset union all coalesce(l_items,ut_varchar2_list()); return l_result; end; member function exclude(a_items varchar2) return ut_equal is l_result ut_equal := self; begin - ut_utils.append_to_list(l_result.exclude_list, a_items); + l_result.exclude_list := l_result.exclude_list multiset union all coalesce(ut_utils.string_to_table(a_items,','),ut_varchar2_list()); + l_result.exclude_list := l_result.exclude_list multiset union all coalesce(ut_utils.string_to_table(a_items,'|'),ut_varchar2_list()); return l_result; end; member function exclude(a_items ut_varchar2_list) return ut_equal is l_result ut_equal := self; - begin - l_result.exclude_list := l_result.exclude_list multiset union all coalesce(a_items,ut_varchar2_list()); + l_items ut_varchar2_list := ut_varchar2_list(); + begin + --Split exclude into single expressions so we cater for concat operator like | + for i in 1..a_items.count loop + --TODO : idoiot proof solution for both include and exclude + l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_items(i),'|'),ut_varchar2_list()); + l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_items(i),','),ut_varchar2_list()); + end loop; + + l_result.exclude_list := l_result.exclude_list multiset union all coalesce(l_items,ut_varchar2_list()); return l_result; end; @@ -194,15 +210,31 @@ create or replace type body ut_equal as l_result ut_equal := self; begin l_result.is_unordered := ut_utils.boolean_to_int(true); - ut_utils.append_to_list(l_result.join_columns, a_columns); + l_result.join_columns := l_result.join_columns multiset union all coalesce(ut_utils.string_to_table(a_columns,','),ut_varchar2_list()); + l_result.join_columns := l_result.join_columns multiset union all coalesce(ut_utils.string_to_table(a_columns,'|'),ut_varchar2_list()); + + select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + bulk collect into l_result.join_on_list + from table(l_result.join_columns); return l_result; end; member function join_by(a_columns ut_varchar2_list) return ut_equal is l_result ut_equal := self; + l_items ut_varchar2_list := ut_varchar2_list(); begin l_result.is_unordered := ut_utils.boolean_to_int(true); - l_result.join_columns := l_result.join_columns multiset union all coalesce(a_columns,ut_varchar2_list()); + for i in 1..a_columns.count loop + --TODO : idoiot proof solution for both include and exclude + l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_columns(i),'|'),ut_varchar2_list()); + l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_columns(i),','),ut_varchar2_list()); + end loop; + l_result.join_columns := l_result.join_columns multiset union all coalesce(l_items,ut_varchar2_list()); + + select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + bulk collect into l_result.join_on_list + from table(l_result.join_columns); + return l_result; end; @@ -235,7 +267,8 @@ create or replace type body ut_equal as l_result := 0 = treat(self.expected as ut_data_value_anydata).compare_implementation(a_actual, get_exclude_xpath(), get_include_xpath()); elsif self.expected is of (ut_data_value_refcursor) then l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); - l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(a_actual, get_exclude_xpath(), get_include_xpath(), get_join_by_xpath(), get_unordered()); + l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, get_exclude_xpath(), + get_include_xpath(), get_join_by_xpath(), get_unordered(), false, false, join_on_list ); else l_result := equal_with_nulls((self.expected = a_actual), a_actual); end if; diff --git a/source/expectations/matchers/ut_equal.tps b/source/expectations/matchers/ut_equal.tps index 0ccbd23c8..3380306e7 100644 --- a/source/expectations/matchers/ut_equal.tps +++ b/source/expectations/matchers/ut_equal.tps @@ -36,6 +36,12 @@ create or replace type ut_equal under ut_comparison_matcher( */ join_columns ut_varchar2_list, + /** + * Holds list of columns to be used as a join PK on sys_refcursor comparision, prefiltered to remvoe + * xpath tag from from + */ + join_on_list ut_varchar2_list, + member procedure init(self in out nocopy ut_equal, a_expected ut_data_value, a_nulls_are_equal boolean), member function equal_with_nulls( self in ut_equal, a_assert_result boolean, a_actual ut_data_value) return boolean, constructor function ut_equal(self in out nocopy ut_equal, a_expected anydata, a_nulls_are_equal boolean := null) return self as result, diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index 7439aea3e..0e570a719 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -50,10 +50,13 @@ create or replace type body ut_include as overriding member function run_matcher(self in out nocopy ut_include, a_actual ut_data_value) return boolean is l_result boolean; + l_actual ut_data_value; begin if self.expected.data_type = a_actual.data_type then - l_result := 0 = treat(self.expected as ut_data_value_refcursor).compare_implementation(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), - true,self.get_inclusion_compare(), self.get_negated()); + l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); + l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, + self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), + true,self.get_inclusion_compare(), self.get_negated(), join_on_list); else l_result := (self as ut_matcher).run_matcher(a_actual); end if; From 107a30bb02337984fdc21b4a1e67e43bf60164a4 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 17 Nov 2018 17:26:26 +0000 Subject: [PATCH 52/83] Updated progress by capturing a nested types in hierarchy structured object type. --- .../data_values/ut_column_info.tpb | 35 --- .../data_values/ut_column_info.tps | 27 --- .../data_values/ut_column_info_rec.tpb | 141 ----------- .../data_values/ut_column_info_rec.tps | 31 --- .../data_values/ut_column_info_tab.tps | 2 - .../data_values/ut_compound_data_helper.pkb | 220 ++++++------------ .../data_values/ut_compound_data_helper.pks | 6 +- .../data_values/ut_cursor_column.tpb | 42 ++++ .../data_values/ut_cursor_column.tps | 33 +++ .../data_values/ut_cursor_column_tab.tps | 2 + .../data_values/ut_cursor_details.tpb | 115 +++++++++ .../data_values/ut_cursor_details.tps | 9 + .../data_values/ut_cursor_info.tpb | 31 --- .../data_values/ut_cursor_info.tps | 7 - .../data_values/ut_data_value_refcursor.tpb | 8 +- .../data_values/ut_data_value_refcursor.tps | 4 +- source/expectations/matchers/ut_equal.tpb | 19 +- source/install.sql | 5 + source/uninstall_objects.sql | 6 + 19 files changed, 301 insertions(+), 442 deletions(-) delete mode 100644 source/expectations/data_values/ut_column_info.tpb delete mode 100644 source/expectations/data_values/ut_column_info.tps delete mode 100644 source/expectations/data_values/ut_column_info_rec.tpb delete mode 100644 source/expectations/data_values/ut_column_info_rec.tps delete mode 100644 source/expectations/data_values/ut_column_info_tab.tps create mode 100644 source/expectations/data_values/ut_cursor_column.tpb create mode 100644 source/expectations/data_values/ut_cursor_column.tps create mode 100644 source/expectations/data_values/ut_cursor_column_tab.tps create mode 100644 source/expectations/data_values/ut_cursor_details.tpb create mode 100644 source/expectations/data_values/ut_cursor_details.tps delete mode 100644 source/expectations/data_values/ut_cursor_info.tpb delete mode 100644 source/expectations/data_values/ut_cursor_info.tps diff --git a/source/expectations/data_values/ut_column_info.tpb b/source/expectations/data_values/ut_column_info.tpb deleted file mode 100644 index 3bd99f15d..000000000 --- a/source/expectations/data_values/ut_column_info.tpb +++ /dev/null @@ -1,35 +0,0 @@ -create or replace type body ut_column_info as - member function get_data_type(a_type_code in integer,a_user_defined in boolean) return varchar2 is - begin - return ut_curr_usr_compound_helper.get_column_type(a_type_code,a_user_defined); - end; - - member procedure init(self in out nocopy ut_column_info, - a_col_type binary_integer, - a_col_name varchar2, - a_col_schema_name varchar2, - a_col_type_name varchar2, - a_col_prec integer, - a_col_scale integer, - a_col_max_len integer, - a_dbms_sql_desc boolean := false, - a_parent_name varchar2 := null) is - begin - self.is_user_defined := 0; - self.column_prec := a_col_prec; - self.column_len := a_col_max_len; - self.column_scale := a_col_scale; - self.column_name := TRIM( BOTH '''' FROM a_col_name); - self.xml_valid_name := '"'||self.column_name||'"'; - self.hashed_name := case when a_parent_name is not null then - ut_compound_data_helper.get_hash(utl_raw.cast_to_raw(a_parent_name||self.column_name)) - else - null - end; - self.column_type := get_data_type(a_col_type,a_dbms_sql_desc); - self.column_schema := a_col_schema_name; - self.is_sql_diffable := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)); - self.is_collection := 0; - end; -end; -/ diff --git a/source/expectations/data_values/ut_column_info.tps b/source/expectations/data_values/ut_column_info.tps deleted file mode 100644 index 27639771f..000000000 --- a/source/expectations/data_values/ut_column_info.tps +++ /dev/null @@ -1,27 +0,0 @@ -create or replace type ut_column_info force authid current_user as object -( - xml_valid_name varchar2(100), - hashed_name raw(30), - column_name varchar2(100), - column_type varchar2(100), - column_schema varchar2(100), - column_prec integer, - column_len integer, - column_scale integer, - is_sql_diffable number(1, 0), - is_collection number(1, 0), - is_user_defined number(1, 0), - member function get_data_type(a_type_code in integer,a_user_defined in boolean) return varchar2, - member procedure init(self in out nocopy ut_column_info, - a_col_type binary_integer, - a_col_name varchar2, - a_col_schema_name varchar2, - a_col_type_name varchar2, - a_col_prec integer, - a_col_scale integer, - a_col_max_len integer, - a_dbms_sql_desc boolean := false, - a_parent_name varchar2 := null) -) -not final not instantiable -/ diff --git a/source/expectations/data_values/ut_column_info_rec.tpb b/source/expectations/data_values/ut_column_info_rec.tpb deleted file mode 100644 index efdbcced1..000000000 --- a/source/expectations/data_values/ut_column_info_rec.tpb +++ /dev/null @@ -1,141 +0,0 @@ -create or replace type body ut_column_info_rec as - - member function get_anytype_attributes_info(a_anytype anytype, a_col_name varchar2) - return ut_column_info_tab is - l_result ut_column_info_tab := ut_column_info_tab(); - l_attribute_typecode pls_integer; - l_aname varchar2(32767); - l_prec pls_integer; - l_scale pls_integer; - l_len pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - l_attr_elt_type anytype; - - function get_anytype_attribute_count(a_anytype anytype) return pls_integer is - l_attribute_typecode pls_integer; - l_schema_name varchar2(32767); - l_version varchar2(32767); - l_type_name varchar2(32767); - l_attributes pls_integer; - l_prec pls_integer; - l_scale pls_integer; - l_len pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - begin - l_attribute_typecode := a_anytype.getinfo(prec => l_prec, - scale => l_scale, - len => l_len, - csid => l_csid, - csfrm => l_csfrm, - schema_name => l_schema_name, - type_name => l_type_name, - version => l_version, - numelems => l_attributes); - return l_attributes; - end; - - begin - for i in 1 .. get_anytype_attribute_count(a_anytype) loop - l_attribute_typecode := a_anytype.getattreleminfo(pos => i, --First attribute - prec => l_prec, - scale => l_scale, - len => l_len, - csid => l_csid, - csfrm => l_csfrm, - attr_elt_type => l_attr_elt_type, - aname => l_aname); - - l_result.extend; - l_result(l_result.last) := ut_column_info_rec(l_attribute_typecode, - l_aname, - null, - null, - l_prec, - l_scale, - l_len, - false, - a_col_name); - end loop; - return l_result; - end; - - member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) - return anytype is - l_anydata anydata; - l_anytype anytype; - l_typecode pls_integer; - - begin - execute immediate 'declare - l_v ' || a_owner || '.' || - a_type_name || '; - begin - :anydata := anydata.convertobject(l_v); - end;' - using in out l_anydata; - - l_typecode := l_anydata.gettype(l_anytype); - - return l_anytype; - end; - - overriding member procedure init(self in out nocopy ut_column_info_rec, - a_col_type binary_integer, - a_col_name varchar2, - a_col_schema_name varchar2, - a_col_type_name varchar2, - a_col_prec integer, - a_col_scale integer, - a_col_max_len integer, - a_dbms_sql_desc boolean := false, - a_parent_name varchar2) is - l_anytype anytype; - begin - self.column_prec := a_col_prec; - self.column_len := a_col_max_len; - self.column_scale := a_col_scale; - self.column_name := TRIM(BOTH '''' FROM a_col_name); - self.xml_valid_name := '"'||self.column_name||'"'; - self.hashed_name := case when a_parent_name is not null then - ut_compound_data_helper.get_hash(utl_raw.cast_to_raw(a_parent_name||self.column_name)) - else - null - end; - self.column_type := a_col_type_name; - self.column_schema := a_col_schema_name; - self.is_sql_diffable := 0; - self.is_collection := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_collection(a_col_schema_name,a_col_type_name)); - self.is_user_defined := 1; - - l_anytype := get_user_defined_type(a_col_schema_name, a_col_type_name); - self.nested_details := get_anytype_attributes_info(l_anytype, self.column_name); - end; - - constructor function ut_column_info_rec(self in out nocopy ut_column_info_rec, - a_col_type binary_integer, - a_col_name varchar2, - a_col_schema_name varchar2, - a_col_type_name varchar2, - a_col_prec integer, - a_col_scale integer, - a_col_max_len integer, - a_dbms_sql_desc boolean := false, - a_parent_name varchar2 := null) - return self as result is - begin - if a_col_type = dbms_sql.user_defined_type then - self.init(a_col_type, a_col_name, a_col_schema_name, a_col_type_name,a_col_prec,a_col_scale,a_col_max_len); - else - (self as ut_column_info).init(a_col_type, - a_col_name, - a_col_schema_name, - a_col_type_name,a_col_prec,a_col_scale,a_col_max_len, - a_dbms_sql_desc, - a_parent_name); - end if; - return; - end; -end; -/ diff --git a/source/expectations/data_values/ut_column_info_rec.tps b/source/expectations/data_values/ut_column_info_rec.tps deleted file mode 100644 index 0059bd08d..000000000 --- a/source/expectations/data_values/ut_column_info_rec.tps +++ /dev/null @@ -1,31 +0,0 @@ -create or replace type ut_column_info_rec under ut_column_info -( - nested_details ut_column_info_tab, - parent_name varchar2(100), - member function get_anytype_attributes_info(a_anytype anytype, a_col_name varchar2) - return ut_column_info_tab, - member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) - return anytype, - overriding member procedure init(self in out nocopy ut_column_info_rec, - a_col_type binary_integer, - a_col_name varchar2, - a_col_schema_name varchar2, - a_col_type_name varchar2, - a_col_prec integer, - a_col_scale integer, - a_col_max_len integer, - a_dbms_sql_desc boolean := false, - a_parent_name varchar2 := null), - constructor function ut_column_info_rec(self in out nocopy ut_column_info_rec, - a_col_type binary_integer, - a_col_name varchar2, - a_col_schema_name varchar2, - a_col_type_name varchar2, - a_col_prec integer, - a_col_scale integer, - a_col_max_len integer, - a_dbms_sql_desc boolean := false, - a_parent_name varchar2 := null) - return self as result -) -/ diff --git a/source/expectations/data_values/ut_column_info_tab.tps b/source/expectations/data_values/ut_column_info_tab.tps deleted file mode 100644 index 27dc44a93..000000000 --- a/source/expectations/data_values/ut_column_info_tab.tps +++ /dev/null @@ -1,2 +0,0 @@ -CREATE OR REPLACE TYPE ut_column_info_tab FORCE AS TABLE OF ut_column_info; -/ diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 613b97bb8..8a7b02079 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -425,7 +425,8 @@ create or replace package body ut_compound_data_helper is return l_no_missing_keys; end; - procedure generate_not_equal_stmt(a_data_info ut_column_info, a_pk_table ut_varchar2_list, a_not_equal_stmt in out nocopy clob) is + procedure generate_not_equal_stmt(a_data_info ut_cursor_column, a_pk_table ut_varchar2_list, a_not_equal_stmt in out nocopy clob, + a_col_name varchar2) is l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); l_index integer; l_sql_stmt varchar2(32767); @@ -444,14 +445,15 @@ create or replace package body ut_compound_data_helper is if not(l_exists) then l_sql_stmt := l_sql_stmt || case when a_not_equal_stmt is null then null else ' or ' end - ||' (decode(a.'||a_data_info.xml_valid_name||','||' e.'||a_data_info.xml_valid_name||',1,0) = 0)'; + ||' (decode(a.'||a_col_name||','||' e.'||a_col_name||',1,0) = 0)'; ut_utils.append_to_clob(a_not_equal_stmt,l_sql_stmt); end if; end; - procedure generate_join_by_stmt(a_data_info ut_column_info, a_pk_table ut_varchar2_list, a_join_by_stmt in out nocopy clob) is + procedure generate_join_by_stmt(a_data_info ut_cursor_column, a_pk_table ut_varchar2_list, a_join_by_stmt in out nocopy clob, + a_col_name varchar2) is l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); - l_index integer ; + l_index integer; l_sql_stmt varchar2(32767); begin if l_pk_tab.count <> 0 then @@ -459,14 +461,7 @@ create or replace package body ut_compound_data_helper is loop if a_data_info.column_name = a_pk_table(l_index) then l_sql_stmt := l_sql_stmt || case when a_join_by_stmt is null then null else ' and ' end; - if a_data_info.is_sql_diffable = 0 then - --TODO : Non diffable is more complex as to hash we need to know how to cast it to raw or clob ? - /*l_sql_stmt := l_ut_owner ||'.ut_compound_data_helper.get_hash( a.'||a_data_info.xml_valid_name||') = ' - ||l_ut_owner ||'.ut_compound_data_helper.get_hash( e.'||a_data_info.xml_valid_name||')';*/ - l_sql_stmt := l_sql_stmt ||' a.'||a_data_info.xml_valid_name||q'[ = ]'||' e.'||a_data_info.xml_valid_name; - elsif a_data_info.is_sql_diffable = 1 then - l_sql_stmt := l_sql_stmt ||' a.'||a_data_info.xml_valid_name||q'[ = ]'||' e.'||a_data_info.xml_valid_name; - end if; + l_sql_stmt := l_sql_stmt ||' a.'||a_col_name||q'[ = ]'||' e.'||a_col_name; end if; exit when (a_data_info.column_name = a_pk_table(l_index)) or l_index = a_pk_table.count; l_index := a_pk_table.next(l_index); @@ -475,34 +470,34 @@ create or replace package body ut_compound_data_helper is end if; end; - procedure generate_equal_sql(a_data_info ut_column_info,a_equal_stmt in out nocopy clob) is + procedure generate_equal_sql(a_equal_stmt in out nocopy clob,a_col_name in varchar2) is l_sql_stmt varchar2(32767); begin - l_sql_stmt := case when a_equal_stmt is null then null else ' and ' end ||' a.'||a_data_info.xml_valid_name||q'[ = ]'||' e.'||a_data_info.xml_valid_name; + l_sql_stmt := case when a_equal_stmt is null then null else ' and ' end ||' a.'||a_col_name||q'[ = ]'||' e.'||a_col_name; ut_utils.append_to_clob(a_equal_stmt,l_sql_stmt); end; - procedure generate_partition_stmt(a_data_info ut_column_info,a_partition_stmt in out nocopy clob) is + procedure generate_partition_stmt(a_partition_stmt in out nocopy clob,a_col_name in varchar2) is l_alias varchar2(10) := 'ucd.'; begin - ut_utils.append_to_clob(a_partition_stmt,case when a_partition_stmt is null then null else ',' end||l_alias||a_data_info.xml_valid_name); + ut_utils.append_to_clob(a_partition_stmt,case when a_partition_stmt is null then null else ',' end||l_alias||a_col_name); end; - procedure generate_select_stmt(a_data_info ut_column_info,a_sql_stmt in out nocopy clob) is + procedure generate_select_stmt(a_data_info ut_cursor_column,a_sql_stmt in out nocopy clob, a_col_name varchar2) is l_sql_stmt clob; l_alias varchar2(10) := 'ucd.'; l_col_syntax varchar2(4000); l_ut_owner varchar2(250) := ut_utils.ut_owner; begin if a_data_info.is_sql_diffable = 0 then - l_col_syntax := l_ut_owner ||'.ut_compound_data_helper.get_hash('||l_alias||a_data_info.xml_valid_name||'.getClobVal()) as '||a_data_info.xml_valid_name ; + l_col_syntax := l_ut_owner ||'.ut_compound_data_helper.get_hash('||l_alias||a_col_name||'.getClobVal()) as '||a_col_name ; else - l_col_syntax := l_alias||a_data_info.xml_valid_name||' as '|| a_data_info.xml_valid_name; + l_col_syntax := l_alias||a_col_name||' as '|| a_col_name; end if; ut_utils.append_to_clob(a_sql_stmt,','||l_col_syntax); end; - procedure generate_xmltab_stmt(a_data_info ut_column_info,a_sql_stmt in out nocopy clob) is + procedure generate_xmltab_stmt(a_data_info ut_cursor_column,a_sql_stmt in out nocopy clob, a_col_name varchar2) is l_sql_stmt varchar2(32767); l_col_type varchar2(4000); begin @@ -513,33 +508,39 @@ create or replace package body ut_compound_data_helper is else l_col_type := a_data_info.column_type||'('||a_data_info.column_len||')'; end if; - l_sql_stmt := ' '||a_data_info.xml_valid_name||' '||l_col_type||q'[ PATH ']'||a_data_info.column_name||q'[',]'; + l_sql_stmt := ' '||a_col_name||' '||l_col_type||q'[ PATH ']'||a_data_info.access_path||q'[',]'; ut_utils.append_to_clob(a_sql_stmt, l_sql_stmt); end; procedure gen_sql_pieces_out_of_cursor(a_data_info ut_data_value_refcursor,a_pk_table ut_varchar2_list, a_xml_stmt out nocopy clob, a_select_stmt out nocopy clob ,a_partition_stmt out nocopy clob, a_equal_stmt out nocopy clob, a_join_by_stmt out nocopy clob, a_not_equal_stmt out nocopy clob) is - l_cursor_info ut_column_info_tab := a_data_info.cursor_col_info.cursor_info; + l_cursor_info ut_cursor_column_tab := a_data_info.cursor_details.cursor_info; l_partition_tmp clob; + l_col_name varchar2(30); begin if l_cursor_info is not null then --Parition by piece ut_utils.append_to_clob(a_partition_stmt,', row_number() over (partition by '); --TODO : Handle nested objects... for i in 1..l_cursor_info.count loop + l_col_name := case when l_cursor_info(i).parent_name is null then + l_cursor_info(i).xml_valid_name + else + utl_raw.cast_to_varchar2(l_cursor_info(i).nested_name) + end; --Get XMLTABLE column list - generate_xmltab_stmt(l_cursor_info(i),a_xml_stmt); + generate_xmltab_stmt(l_cursor_info(i),a_xml_stmt,l_col_name); --Get Select statment list of columns - generate_select_stmt(l_cursor_info(i),a_select_stmt); + generate_select_stmt(l_cursor_info(i),a_select_stmt,l_col_name); --Get columns by which we partition - generate_partition_stmt(l_cursor_info(i),l_partition_tmp); + generate_partition_stmt(l_partition_tmp,l_col_name); --Get equal statement - generate_equal_sql(l_cursor_info(i),a_equal_stmt); + generate_equal_sql(a_equal_stmt,l_col_name); --Generate join by stmt - generate_join_by_stmt(l_cursor_info(i),a_pk_table,a_join_by_stmt); + generate_join_by_stmt(l_cursor_info(i),a_pk_table,a_join_by_stmt,l_col_name); --Generate not equal stmt - generate_not_equal_stmt(l_cursor_info(i),a_pk_table,a_not_equal_stmt); + generate_not_equal_stmt(l_cursor_info(i),a_pk_table,a_not_equal_stmt,l_col_name); end loop; --Finish parition by ut_utils.append_to_clob(a_partition_stmt,l_partition_tmp||' order by '||l_partition_tmp||' ) dup_no '); @@ -563,18 +564,6 @@ create or replace package body ut_compound_data_helper is l_equal_stmt clob; l_join_on_stmt clob; l_not_equal_stmt clob; - l_column_filter varchar2(32767); - - function get_filtered_columns_name (a_columns_info in xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2) return ut_varchar2_list is - l_columns_info ut_varchar2_list := ut_varchar2_list(); - begin - execute immediate 'with xmlt as ( select :xml_data as item_data from dual ),' - ||'filtered as (select '||get_columns_row_filter(a_exclude_xpath,a_include_xpath) ||' from xmlt ucd) ' - ||q'[select '"'||xt.name||'"' from filtered f, xmltable( '/ROW/*' passing f.item_data columns ]' - ||q'[name VARCHAR2(4000) PATH '@xml_valid_name') xt]' bulk collect into l_columns_info - using a_columns_info,a_exclude_xpath,a_include_xpath; - return l_columns_info; - end; function get_join_type(a_inclusion_compare in boolean,a_negated in boolean) return varchar2 is begin @@ -590,9 +579,7 @@ create or replace package body ut_compound_data_helper is begin dbms_lob.createtemporary(l_compare_sql, true); - --TODO: Resolve issues with collection and nested tables, can we extract by internal column name if defined e.g. xml of colval.id.getclobval() - --TODO: Comment better all pieces - l_column_filter := get_columns_row_filter(a_exclude_xpath, a_include_xpath); + --TODO: Resolve issues with collection and nested tables, can we extract by internal column name if defined e.g. xml of colval.id.getclobval() gen_sql_pieces_out_of_cursor(a_other, a_join_by_list, l_xmltable_stmt, l_select_stmt, l_partition_stmt, l_equal_stmt, @@ -711,110 +698,52 @@ create or replace package body ut_compound_data_helper is begin return g_diff_count; end; - - function get_child(a_parent in varchar2 default null) return ut_varchar2_list is - l_out_tab ut_varchar2_list := ut_varchar2_list(); - cursor c_child(cp_parent in varchar2) is - with sorted as - (select r_num, - regexp_substr(t.column_value, '[^/]+', 1, commas.column_value) as colval, - commas.column_value lev - from (select row_number() over(order by 1) r_num, - column_value - from ((table(g_filter_tab)))) t, - table(cast(multiset - (select level - from dual - connect by level <= - length(regexp_replace(t.column_value, - '[^/]+')) + 1) as - sys.odcinumberlist)) commas - order by r_num, - lev), - hier as - (select r_num, - lev, - colval, - lag(colval, 1) over(partition by r_num order by lev) parent - from sorted) - select distinct colval - from hier - where nvl(parent, 1) = nvl(cp_parent, 1); - - begin - open c_child(a_parent); - fetch c_child bulk collect - into l_out_tab; - close c_child; - return l_out_tab; - end; - function inc_cursors_columns(a_column_info_tab ut_column_info_tab,a_current_list ut_varchar2_list) - return ut_column_info_tab is - l_result ut_column_info_tab := ut_column_info_tab(); - l_record ut_column_info_rec; - l_index integer; - begin - for lst in 1..a_current_list.count loop - l_index := a_column_info_tab.first; - loop - if a_current_list(lst) = a_column_info_tab(l_index).column_name then - l_result.extend; - l_record := treat(a_column_info_tab(l_index) as ut_column_info_rec); - - if treat(a_column_info_tab(l_index) as ut_column_info_rec).nested_details is not null then - l_record.nested_details := inc_cursors_columns(treat(a_column_info_tab(l_index) as ut_column_info_rec).nested_details,get_child(a_column_info_tab(l_index).column_name)); - end if; - - l_result(l_result.last) := l_record; - end if; - exit when (a_current_list(lst) = a_column_info_tab(l_index).column_name) or (l_index = a_column_info_tab.count); - l_index := a_column_info_tab.next(l_index); - end loop; - end loop; - - return l_result; - end; + function filter_out_cols(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list,a_include boolean) + return ut_cursor_column_tab is + l_sql varchar2(32767) := + q'[with + sorted as + (select r_num,regexp_substr(t.column_value, '[^/]+', 1, commas.column_value) as colval,commas.column_value lev + from (select row_number() over(order by 1) r_num, column_value from ((table(:a_current_list)))) t, + table(cast(multiset + (select level from dual connect by level <= length(regexp_replace(t.column_value,'[^/]+')) + 1) as sys.odcinumberlist)) commas + order by r_num,lev), + hier as + (select r_num,lev,colval column_name,lag(colval, 1) over(partition by r_num order by lev) parent_name from sorted), + constructed as ( + select lev,column_name,parent_name from hier), + t1(column_name, parent_name) AS ( + select column_name,parent_name from table(:a_cursor_info) where parent_name is null + union all + select t2.column_name,t2.parent_name from table(:a_cursor_info) t2, t1 where t2.parent_name = t1.column_name) + select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name, i.column_prec,i.column_scale,i.column_len, i.parent_name, + i.hierarchy_level,i.column_position, i.column_type) + from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name) + ]'; - function exc_cursors_columns(a_column_info_tab ut_column_info_tab,a_current_list ut_varchar2_list) - return ut_column_info_tab is - l_result ut_column_info_tab := ut_column_info_tab(); - l_record ut_column_info_rec; - l_index integer; - l_exists boolean := false; + l_result ut_cursor_column_tab := ut_cursor_column_tab(); begin - --TODO : Optimize search using while or exists operator ? - for lst in 1..a_column_info_tab.count loop - l_index := a_current_list.first; - loop - if a_current_list(l_index) = a_column_info_tab(lst).column_name then - l_exists := true; - end if; - exit when (a_current_list(l_index) = a_column_info_tab(lst).column_name) or (l_index = a_current_list.count); - l_index := a_current_list.next(l_index); - end loop; - - if not(l_exists) then - l_result.extend; - l_record := treat(a_column_info_tab(lst) as ut_column_info_rec); - if treat(a_column_info_tab(lst) as ut_column_info_rec).nested_details is not null then - l_record.nested_details := exc_cursors_columns(treat(a_column_info_tab(lst) as ut_column_info_rec).nested_details,get_child(a_column_info_tab(lst).column_name)); - end if; - l_result(l_result.last) := l_record; - end if; - l_exists := false; - end loop; - return l_result; + --TODO : Get this query tidy up + if a_include then + l_sql := l_sql || ' join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name)'; + else + l_sql := l_sql ||'left outer join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name) + where c.column_name is null'; + end if; + + execute immediate l_sql bulk collect into l_result + using a_current_list,a_cursor_info,a_cursor_info,a_cursor_info; + + return l_result; end; - - function inc_exc_columns_from_cursor (a_cursor_info ut_column_info_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) - return ut_column_info_tab is + + function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) + return ut_cursor_column_tab is l_filtered_set ut_varchar2_list := ut_varchar2_list(); - l_result ut_column_info_tab := ut_column_info_tab(); + l_result ut_cursor_column_tab := ut_cursor_column_tab(); l_include boolean; begin - g_filter_tab := ut_varchar2_list(); - -- if include and exclude is not null its columns from include minus exclude -- If inlcude is not null and exclude is null cursor will have only include -- If exclude is not null and include is null cursor will have all except exclude @@ -841,15 +770,12 @@ create or replace package body ut_compound_data_helper is elsif a_cursor_info is not null then l_result:= a_cursor_info; else - l_result := ut_column_info_tab(); + l_result := ut_cursor_column_tab(); end if; - g_filter_tab := l_filtered_set; - if l_filtered_set.count <> 0 and l_include then - l_result := inc_cursors_columns(a_cursor_info,get_child()); - elsif l_filtered_set.count <> 0 and not(l_include) then - l_result := exc_cursors_columns(a_cursor_info,get_child()); - end if; + if l_filtered_set.count > 0 then + l_result := filter_out_cols(a_cursor_info,l_filtered_set,l_include); + end if; return l_result; end; diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 924593c62..98913531e 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -101,9 +101,9 @@ create or replace package ut_compound_data_helper authid definer is procedure cleanup_diff; function get_rows_diff_count return integer; - - function inc_exc_columns_from_cursor (a_cursor_info ut_column_info_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) - return ut_column_info_tab; + + function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) + return ut_cursor_column_tab; end; / diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb new file mode 100644 index 000000000..dbf37b518 --- /dev/null +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -0,0 +1,42 @@ +create or replace type body ut_cursor_column as + + member procedure init(self in out nocopy ut_cursor_column, + a_col_name varchar2, a_col_schema_name varchar2, + a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, + a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level number := 1, + a_col_position number, a_col_type varchar2) is + begin + self.parent_name := null; + self.hierarchy_level := a_hierarchy_level; + self.column_position := a_col_position; + self.is_user_defined := 0; + self.column_prec := a_col_prec; + self.column_len := a_col_max_len; + self.column_scale := a_col_scale; + self.column_name := TRIM( BOTH '''' FROM a_col_name); + self.column_type_name := a_col_type_name; + self.access_path := case when self.parent_name is null then self.column_name else self.parent_name||'/'||self.column_name end; + self.nested_name := case when self.parent_name is null then + null + else + ut_compound_data_helper.get_hash(utl_raw.cast_to_raw(self.parent_name||'/'||self.column_name)) + end; + self.xml_valid_name := '"'||self.column_name||'"'; + self.column_type := a_col_type; + self.column_schema := a_col_schema_name; + self.is_sql_diffable := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)); + self.is_collection := 0; + end; + + constructor function ut_cursor_column( self in out nocopy ut_cursor_column, + a_col_name varchar2, a_col_schema_name varchar2, + a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, + a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level number := 1, + a_col_position number, a_col_type in varchar2) return self as result is + begin + init(a_col_name, a_col_schema_name, a_col_type_name, a_col_prec, + a_col_scale, a_col_max_len, a_parent_name,a_hierarchy_level, a_col_position, a_col_type); + return; + end; +end; +/ diff --git a/source/expectations/data_values/ut_cursor_column.tps b/source/expectations/data_values/ut_cursor_column.tps new file mode 100644 index 000000000..0602b1ceb --- /dev/null +++ b/source/expectations/data_values/ut_cursor_column.tps @@ -0,0 +1,33 @@ +create or replace type ut_cursor_column force authid current_user as object +( + parent_name varchar2(100), + access_path varchar2(500), + nested_name raw(30), + hierarchy_level number, + column_position number, + xml_valid_name varchar2(100), + column_name varchar2(100), + column_type varchar2(100), + column_type_name varchar2(100), + column_schema varchar2(100), + column_prec integer, + column_len integer, + column_scale integer, + is_sql_diffable number(1, 0), + is_collection number(1, 0), + is_user_defined number(1, 0), + + member procedure init(self in out nocopy ut_cursor_column, + a_col_name varchar2, a_col_schema_name varchar2, + a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, + a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level number := 1, + a_col_position number, a_col_type in varchar2), + + constructor function ut_cursor_column( self in out nocopy ut_cursor_column, + a_col_name varchar2, a_col_schema_name varchar2, + a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, + a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level number := 1, + a_col_position number, a_col_type in varchar2) + return self as result +) +/ diff --git a/source/expectations/data_values/ut_cursor_column_tab.tps b/source/expectations/data_values/ut_cursor_column_tab.tps new file mode 100644 index 000000000..05516854a --- /dev/null +++ b/source/expectations/data_values/ut_cursor_column_tab.tps @@ -0,0 +1,2 @@ +create or replace type ut_cursor_column_tab as table of ut_cursor_column +/ \ No newline at end of file diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb new file mode 100644 index 000000000..2d0b5a67f --- /dev/null +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -0,0 +1,115 @@ +create or replace type body ut_cursor_details as + + member function get_anytype_attribute_count(a_anytype anytype) return pls_integer is + l_attribute_typecode pls_integer; + l_schema_name varchar2(32767); + l_version varchar2(32767); + l_type_name varchar2(32767); + l_attributes pls_integer; + l_prec pls_integer; + l_scale pls_integer; + l_len pls_integer; + l_csid pls_integer; + l_csfrm pls_integer; + begin + l_attribute_typecode := a_anytype.getinfo(prec => l_prec, + scale => l_scale, + len => l_len, + csid => l_csid, + csfrm => l_csfrm, + schema_name => l_schema_name, + type_name => l_type_name, + version => l_version, + numelems => l_attributes); + return l_attributes; + end; + + member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) + return anytype is + l_anydata anydata; + l_anytype anytype; + l_typecode pls_integer; + + begin + execute immediate 'declare + l_v ' || a_owner || '.' || + a_type_name || '; + begin + :anydata := anydata.convertobject(l_v); + end;' + using in out l_anydata; + + l_typecode := l_anydata.gettype(l_anytype); + + return l_anytype; + end; + + constructor function ut_cursor_details(self in out nocopy ut_cursor_details, + a_cursor in out nocopy sys_refcursor) + return self as result is + l_cursor_number integer; + l_columns_count pls_integer; + l_columns_desc dbms_sql.desc_tab3; + l_attribute_typecode pls_integer; + l_aname varchar2(32767); + l_prec pls_integer; + l_scale pls_integer; + l_len pls_integer; + l_csid pls_integer; + l_csfrm pls_integer; + l_attr_elt_type anytype; + l_anytype anytype; + + begin + self.cursor_info := ut_cursor_column_tab(); + l_cursor_number := dbms_sql.to_cursor_number(a_cursor); + dbms_sql.describe_columns3(l_cursor_number, + l_columns_count, + l_columns_desc); + a_cursor := dbms_sql.to_refcursor(l_cursor_number); + + for cur in 1 .. l_columns_count loop + self.cursor_info.extend; + self.cursor_info(cursor_info.last) := ut_cursor_column( l_columns_desc(cur).col_name, + l_columns_desc(cur).col_schema_name, + l_columns_desc(cur).col_type_name, + l_columns_desc(cur).col_precision, + l_columns_desc(cur).col_scale, + l_columns_desc(cur).col_max_len, + null, + 1, + cur, + ut_curr_usr_compound_helper.get_column_type(l_columns_desc(cur).col_type,false) + ); + if l_columns_desc(cur).col_type = dbms_sql.user_defined_type then + l_anytype := get_user_defined_type(l_columns_desc(cur).col_schema_name , l_columns_desc(cur).col_type_name ); + for i in 1 .. get_anytype_attribute_count(l_anytype) loop + l_attribute_typecode := l_anytype.getattreleminfo(pos => i, --First attribute + prec => l_prec, + scale => l_scale, + len => l_len, + csid => l_csid, + csfrm => l_csfrm, + attr_elt_type => l_attr_elt_type, + aname => l_aname); + + self.cursor_info.extend; + self.cursor_info(cursor_info.last) := ut_cursor_column( l_aname, + null, + null, + l_prec, + l_scale, + l_len, + l_columns_desc(i).col_name, + 2, + i, + ut_curr_usr_compound_helper.get_column_type(l_attribute_typecode,true) + ); + end loop; + end if; + end loop; + + return; + end; +end; +/ diff --git a/source/expectations/data_values/ut_cursor_details.tps b/source/expectations/data_values/ut_cursor_details.tps new file mode 100644 index 000000000..00f03e676 --- /dev/null +++ b/source/expectations/data_values/ut_cursor_details.tps @@ -0,0 +1,9 @@ +create or replace type ut_cursor_details force authid current_user as object +( + cursor_info ut_cursor_column_tab, + member function get_anytype_attribute_count(a_anytype anytype) return pls_integer, + member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return anytype, + constructor function ut_cursor_details(self in out nocopy ut_cursor_details,a_cursor in out nocopy sys_refcursor) + return self as result +) +/ diff --git a/source/expectations/data_values/ut_cursor_info.tpb b/source/expectations/data_values/ut_cursor_info.tpb deleted file mode 100644 index 819ac704a..000000000 --- a/source/expectations/data_values/ut_cursor_info.tpb +++ /dev/null @@ -1,31 +0,0 @@ -create or replace type body ut_cursor_info as - constructor function ut_cursor_info(self in out nocopy ut_cursor_info, - a_cursor in out nocopy sys_refcursor) - return self as result is - l_cursor_number integer; - l_columns_count pls_integer; - l_columns_desc dbms_sql.desc_tab3; - begin - self.cursor_info := ut_column_info_tab(); - l_cursor_number := dbms_sql.to_cursor_number(a_cursor); - dbms_sql.describe_columns3(l_cursor_number, - l_columns_count, - l_columns_desc); - a_cursor := dbms_sql.to_refcursor(l_cursor_number); - - for i in 1 .. l_columns_count loop - self.cursor_info.extend; - self.cursor_info(cursor_info.last) := ut_column_info_rec(l_columns_desc(i).col_type, - l_columns_desc(i).col_name, - l_columns_desc(i).col_schema_name, - l_columns_desc(i).col_type_name, - l_columns_desc(i).col_precision, - l_columns_desc(i).col_scale, - l_columns_desc(i).col_max_len, - true); - end loop; - - return; - end ut_cursor_info; -end; -/ diff --git a/source/expectations/data_values/ut_cursor_info.tps b/source/expectations/data_values/ut_cursor_info.tps deleted file mode 100644 index d373ef9a0..000000000 --- a/source/expectations/data_values/ut_cursor_info.tps +++ /dev/null @@ -1,7 +0,0 @@ -create or replace type ut_cursor_info force authid current_user as object -( - cursor_info ut_column_info_tab, - constructor function ut_cursor_info(self in out nocopy ut_cursor_info,a_cursor in out nocopy sys_refcursor) - return self as result -) -/ diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 84552ed4a..c63583469 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -48,7 +48,7 @@ create or replace type body ut_data_value_refcursor as self.elements_count := 0; self.columns_info := ut_curr_usr_compound_helper.extract_min_col_info(self.col_info_desc); - self.cursor_col_info := ut_cursor_info(l_cursor); + self.cursor_details := ut_cursor_details(l_cursor); -- We use DBMS_XMLGEN in order to: -- 1) be able to process data in bulks (set of rows) @@ -271,9 +271,9 @@ create or replace type body ut_data_value_refcursor as member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor is l_result ut_data_value_refcursor := self; begin - if l_result.cursor_col_info.cursor_info is not null then - l_result.cursor_col_info.cursor_info := ut_compound_data_helper.inc_exc_columns_from_cursor(l_result.cursor_col_info.cursor_info,a_exclude_xpath,a_include_xpath); - end if; + if l_result.cursor_details.cursor_info is not null then + l_result.cursor_details.cursor_info := ut_compound_data_helper.inc_exc_columns_from_cursor(l_result.cursor_details.cursor_info,a_exclude_xpath,a_include_xpath); + end if; return l_result; end; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 790ddf895..01b35d745 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -46,8 +46,8 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( /* *columns info - */ - cursor_col_info ut_cursor_info, + */ + cursor_details ut_cursor_details, constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) return self as result, member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index 854b4eef0..0e80d9aea 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -158,8 +158,8 @@ create or replace type body ut_equal as member function include(a_items varchar2) return ut_equal is l_result ut_equal := self; begin - l_result.include_list := l_result.include_list multiset union all coalesce(ut_utils.string_to_table(a_items,','),ut_varchar2_list()); - l_result.include_list := l_result.include_list multiset union all coalesce(ut_utils.string_to_table(a_items,'|'),ut_varchar2_list()); + --TODO : thats poorly done + l_result.include_list := l_result.include_list multiset union coalesce(ut_utils.string_to_table(REPLACE(a_items,'|',','),','),ut_varchar2_list()); return l_result; end; @@ -169,8 +169,7 @@ create or replace type body ut_equal as begin --Split exclude into single expressions so we cater for concat operator like | for i in 1..a_items.count loop - l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_items(i),'|'),ut_varchar2_list()); - l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_items(i),','),ut_varchar2_list()); + l_items := l_items multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_items(i),'|',','),','),ut_varchar2_list()); end loop; l_result.include_list := l_result.include_list multiset union all coalesce(l_items,ut_varchar2_list()); return l_result; @@ -179,8 +178,7 @@ create or replace type body ut_equal as member function exclude(a_items varchar2) return ut_equal is l_result ut_equal := self; begin - l_result.exclude_list := l_result.exclude_list multiset union all coalesce(ut_utils.string_to_table(a_items,','),ut_varchar2_list()); - l_result.exclude_list := l_result.exclude_list multiset union all coalesce(ut_utils.string_to_table(a_items,'|'),ut_varchar2_list()); + l_result.exclude_list := l_result.exclude_list multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_items,'|',','),','),ut_varchar2_list()); return l_result; end; @@ -191,8 +189,7 @@ create or replace type body ut_equal as --Split exclude into single expressions so we cater for concat operator like | for i in 1..a_items.count loop --TODO : idoiot proof solution for both include and exclude - l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_items(i),'|'),ut_varchar2_list()); - l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_items(i),','),ut_varchar2_list()); + l_items := l_items multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_items(i),'|',','),','),ut_varchar2_list()); end loop; l_result.exclude_list := l_result.exclude_list multiset union all coalesce(l_items,ut_varchar2_list()); @@ -210,8 +207,7 @@ create or replace type body ut_equal as l_result ut_equal := self; begin l_result.is_unordered := ut_utils.boolean_to_int(true); - l_result.join_columns := l_result.join_columns multiset union all coalesce(ut_utils.string_to_table(a_columns,','),ut_varchar2_list()); - l_result.join_columns := l_result.join_columns multiset union all coalesce(ut_utils.string_to_table(a_columns,'|'),ut_varchar2_list()); + l_result.join_columns := l_result.join_columns multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_columns,'|',','),','),ut_varchar2_list()); select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names bulk collect into l_result.join_on_list @@ -226,8 +222,7 @@ create or replace type body ut_equal as l_result.is_unordered := ut_utils.boolean_to_int(true); for i in 1..a_columns.count loop --TODO : idoiot proof solution for both include and exclude - l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_columns(i),'|'),ut_varchar2_list()); - l_items := l_items multiset union all coalesce(ut_utils.string_to_table(a_columns(i),','),ut_varchar2_list()); + l_items := l_items multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_columns(i),'|',','),','),ut_varchar2_list()); end loop; l_result.join_columns := l_result.join_columns multiset union all coalesce(l_items,ut_varchar2_list()); diff --git a/source/install.sql b/source/install.sql index b58fb4e24..6ae9ecf95 100644 --- a/source/install.sql +++ b/source/install.sql @@ -169,6 +169,9 @@ prompt Installing DBMSPLSQL Tables objects into &&ut3_owner schema --expectations and matchers @@install_component.sql 'expectations/data_values/ut_compound_data_tmp.sql' @@install_component.sql 'expectations/data_values/ut_compound_data_diff_tmp.sql' +@@install_component.sql 'expectations/data_values/ut_cursor_column.tps' +@@install_component.sql 'expectations/data_values/ut_cursor_column_tab.tps' +@@install_component.sql 'expectations/data_values/ut_cursor_details.tps' @@install_component.sql 'expectations/data_values/ut_data_value.tps' @@install_component.sql 'expectations/data_values/ut_compound_data_value.tps' @@install_component.sql 'expectations/data_values/ut_data_value_anydata.tps' @@ -209,6 +212,8 @@ prompt Installing DBMSPLSQL Tables objects into &&ut3_owner schema @@install_component.sql 'expectations/matchers/ut_be_empty.tps' @@install_component.sql 'expectations/matchers/ut_match.tps' @@install_component.sql 'expectations/ut_expectation.tps' +@@install_component.sql 'expectations/data_values/ut_cursor_column.tpb' +@@install_component.sql 'expectations/data_values/ut_cursor_details.tpb' @@install_component.sql 'expectations/ut_expectation_compound.tps' @@install_component.sql 'expectations/data_values/ut_data_value.tpb' @@install_component.sql 'expectations/data_values/ut_compound_data_value.tpb' diff --git a/source/uninstall_objects.sql b/source/uninstall_objects.sql index 0e059be56..b54c3b96c 100644 --- a/source/uninstall_objects.sql +++ b/source/uninstall_objects.sql @@ -131,6 +131,12 @@ drop type ut_data_value_xmltype force; drop type ut_data_value force; +drop type ut_cursor_details force; + +drop type ut_cursor_column_tab force; + +drop type ut_cursor_column force; + drop table ut_compound_data_tmp; drop table ut_compound_data_diff_tmp; From 6726f1a1d0aa0136a99a49bc0dd45728c1aa7bf8 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 18 Nov 2018 22:22:41 +0000 Subject: [PATCH 53/83] Saving progress --- .../data_values/ut_compound_data_helper.pkb | 94 ++++++++++---- .../data_values/ut_compound_data_helper.pks | 15 ++- .../data_values/ut_compound_data_value.tpb | 19 +-- .../data_values/ut_compound_data_value.tps | 5 +- .../ut_curr_usr_compound_helper.pkb | 9 +- .../ut_curr_usr_compound_helper.pks | 3 +- .../data_values/ut_cursor_column.tpb | 9 +- .../data_values/ut_cursor_column.tps | 2 +- .../data_values/ut_cursor_details.tpb | 122 ++++++++++-------- .../data_values/ut_cursor_details.tps | 1 + .../data_values/ut_data_value_refcursor.tpb | 36 +++--- .../data_values/ut_data_value_refcursor.tps | 5 +- source/expectations/matchers/ut_equal.tpb | 18 ++- source/expectations/matchers/ut_equal.tps | 1 + source/expectations/matchers/ut_include.tpb | 6 +- source/expectations/ut_expectation.tpb | 1 - .../expectations/test_expectations_cursor.pkb | 76 +++++++++-- .../expectations/test_expectations_cursor.pks | 8 +- 18 files changed, 279 insertions(+), 151 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 8a7b02079..69eca4f3d 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -184,9 +184,7 @@ create or replace package body ut_compound_data_helper is l_act_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','act_item_data'); l_exp_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','exp_item_data'); - --TODO: Generate SQL based on input as unorder join should aggregate - - l_sql := q'[with exp as ( + l_sql := q'[with exp as ( select exp_item_data, exp_data_id, item_no rn,rownum col_no, nvl2(exp_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,exp_item_data),null) pk_value, s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val @@ -366,6 +364,11 @@ create or replace package body ut_compound_data_helper is return dbms_crypto.hash(a_data, a_hash_type); end; + function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer :=30) return number is + begin + return dbms_utility.get_hash_value(a_string,a_base,a_size); + end; + function columns_hash( a_data_value_cursor ut_data_value_refcursor, a_exclude_xpath varchar2, a_include_xpath varchar2, a_hash_type binary_integer := dbms_crypto.hash_sh1 @@ -435,10 +438,10 @@ create or replace package body ut_compound_data_helper is l_index := l_pk_tab.first; if l_pk_tab.count > 0 then loop - if a_data_info.column_name = l_pk_tab(l_index) then + if a_data_info.access_path = l_pk_tab(l_index) then l_exists := true; end if; - exit when l_index = l_pk_tab.count or (a_data_info.column_name = l_pk_tab(l_index)); + exit when l_index = l_pk_tab.count or (a_data_info.access_path = l_pk_tab(l_index)); l_index := a_pk_table.next(l_index); end loop; end if; @@ -459,12 +462,12 @@ create or replace package body ut_compound_data_helper is if l_pk_tab.count <> 0 then l_index:= l_pk_tab.first; loop - if a_data_info.column_name = a_pk_table(l_index) then - l_sql_stmt := l_sql_stmt || case when a_join_by_stmt is null then null else ' and ' end; + if a_data_info.access_path = l_pk_tab(l_index) then + l_sql_stmt := case when a_join_by_stmt is null then null else ' and ' end; l_sql_stmt := l_sql_stmt ||' a.'||a_col_name||q'[ = ]'||' e.'||a_col_name; end if; - exit when (a_data_info.column_name = a_pk_table(l_index)) or l_index = a_pk_table.count; - l_index := a_pk_table.next(l_index); + exit when (a_data_info.access_path = l_pk_tab(l_index)) or l_index = l_pk_tab.count; + l_index := l_pk_tab.next(l_index); end loop; ut_utils.append_to_clob(a_join_by_stmt,l_sql_stmt); end if; @@ -477,10 +480,26 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(a_equal_stmt,l_sql_stmt); end; - procedure generate_partition_stmt(a_partition_stmt in out nocopy clob,a_col_name in varchar2) is + procedure generate_partition_stmt(a_data_info ut_cursor_column, a_partition_stmt in out nocopy clob,a_pk_table in ut_varchar2_list,a_col_name in varchar2) is l_alias varchar2(10) := 'ucd.'; + l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); + l_index integer; + l_sql_stmt varchar2(32767); begin - ut_utils.append_to_clob(a_partition_stmt,case when a_partition_stmt is null then null else ',' end||l_alias||a_col_name); + if l_pk_tab.count <> 0 then + l_index:= l_pk_tab.first; + loop + if a_data_info.access_path = l_pk_tab(l_index) then + l_sql_stmt := case when a_partition_stmt is null then null else ',' end; + l_sql_stmt := l_sql_stmt ||l_alias||a_col_name; + end if; + exit when (a_data_info.access_path = l_pk_tab(l_index)) or l_index = l_pk_tab.count; + l_index := l_pk_tab.next(l_index); + end loop; + else + l_sql_stmt := case when a_partition_stmt is null then null else ',' end ||l_alias||a_col_name; + end if; + ut_utils.append_to_clob(a_partition_stmt,l_sql_stmt); end; procedure generate_select_stmt(a_data_info ut_cursor_column,a_sql_stmt in out nocopy clob, a_col_name varchar2) is @@ -506,7 +525,7 @@ create or replace package body ut_compound_data_helper is elsif a_data_info.is_sql_diffable = 1 and a_data_info.column_type = 'DATE' then l_col_type := 'TIMESTAMP'; else - l_col_type := a_data_info.column_type||'('||a_data_info.column_len||')'; + l_col_type := a_data_info.column_type||case when a_data_info.column_len is not null then '('||a_data_info.column_len||')' else null end; end if; l_sql_stmt := ' '||a_col_name||' '||l_col_type||q'[ PATH ']'||a_data_info.access_path||q'[',]'; ut_utils.append_to_clob(a_sql_stmt, l_sql_stmt); @@ -517,30 +536,32 @@ create or replace package body ut_compound_data_helper is a_not_equal_stmt out nocopy clob) is l_cursor_info ut_cursor_column_tab := a_data_info.cursor_details.cursor_info; l_partition_tmp clob; - l_col_name varchar2(30); + l_col_name varchar2(100); begin if l_cursor_info is not null then - --Parition by piece + --Parition by piece + --TODO : Collection is intersting exmaple that we probably has to extract full xml and hash it. ut_utils.append_to_clob(a_partition_stmt,', row_number() over (partition by '); - --TODO : Handle nested objects... for i in 1..l_cursor_info.count loop + if l_cursor_info(i).is_user_defined = 0 then l_col_name := case when l_cursor_info(i).parent_name is null then l_cursor_info(i).xml_valid_name else - utl_raw.cast_to_varchar2(l_cursor_info(i).nested_name) + l_cursor_info(i).nested_name end; --Get XMLTABLE column list generate_xmltab_stmt(l_cursor_info(i),a_xml_stmt,l_col_name); --Get Select statment list of columns generate_select_stmt(l_cursor_info(i),a_select_stmt,l_col_name); --Get columns by which we partition - generate_partition_stmt(l_partition_tmp,l_col_name); + generate_partition_stmt(l_cursor_info(i),l_partition_tmp,a_pk_table,l_col_name); --Get equal statement generate_equal_sql(a_equal_stmt,l_col_name); --Generate join by stmt generate_join_by_stmt(l_cursor_info(i),a_pk_table,a_join_by_stmt,l_col_name); --Generate not equal stmt generate_not_equal_stmt(l_cursor_info(i),a_pk_table,a_not_equal_stmt,l_col_name); + end if; end loop; --Finish parition by ut_utils.append_to_clob(a_partition_stmt,l_partition_tmp||' order by '||l_partition_tmp||' ) dup_no '); @@ -550,9 +571,8 @@ create or replace package body ut_compound_data_helper is end if; end; - function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean, - a_unordered boolean, a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=null ) return clob is + function gen_compare_sql(a_column_info xmltype,a_inclusion_type boolean, a_is_negated boolean,a_unordered boolean, + a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob is l_compare_sql clob; l_temp_string varchar2(32767); @@ -638,10 +658,10 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql,' e.dup_no = a.dup_no and '); end if; - if a_join_by_xpath is null and a_unordered then + if (a_join_by_list.count = 0) and a_unordered then -- If no key defined do the join on all columns ut_utils.append_to_clob(l_compare_sql,l_equal_stmt); - elsif a_join_by_xpath is not null and a_unordered then + elsif (a_join_by_list.count > 0) and a_unordered then -- If key defined do the join or these and where on diffrences ut_utils.append_to_clob(l_compare_sql,l_join_on_stmt); elsif not a_unordered then @@ -650,7 +670,7 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(l_compare_sql,' ) where '); - if (a_join_by_xpath is not null) and (a_unordered) and (not a_is_negated) then + if (a_join_by_list.count > 0) and (a_unordered) and (not a_is_negated) then if l_not_equal_stmt is not null then ut_utils.append_to_clob(l_compare_sql,' ( '||l_not_equal_stmt||' ) or '); end if; @@ -663,6 +683,8 @@ create or replace package body ut_compound_data_helper is --If its inlcusion we expect a actual set to fully match and have no extra elements over expected if a_inclusion_type and not(a_is_negated) then l_temp_string := ' ( a.data_id is null ) '; + elsif a_inclusion_type and a_is_negated then + l_temp_string := ' 1 = 1 '; else l_temp_string := ' (a.data_id is null or e.data_id is null) '; end if; @@ -699,9 +721,8 @@ create or replace package body ut_compound_data_helper is return g_diff_count; end; - function filter_out_cols(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list,a_include boolean) - return ut_cursor_column_tab is - l_sql varchar2(32767) := + function get_cursor_vs_list_sql return varchar2 is + l_sql varchar2(32767) := q'[with sorted as (select r_num,regexp_substr(t.column_value, '[^/]+', 1, commas.column_value) as colval,commas.column_value lev @@ -721,10 +742,15 @@ create or replace package body ut_compound_data_helper is i.hierarchy_level,i.column_position, i.column_type) from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name) ]'; + begin + return l_sql; + end; + function filter_out_cols(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list,a_include boolean := true) + return ut_cursor_column_tab is + l_sql varchar2(32767) := get_cursor_vs_list_sql; l_result ut_cursor_column_tab := ut_cursor_column_tab(); begin - --TODO : Get this query tidy up if a_include then l_sql := l_sql || ' join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name)'; else @@ -738,6 +764,20 @@ create or replace package body ut_compound_data_helper is return l_result; end; + function compare_cursor_to_columns(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list) + return ut_cursor_column_tab is + l_sql varchar2(32767) := get_cursor_vs_list_sql; + l_result ut_cursor_column_tab := ut_cursor_column_tab(); + begin + l_sql := l_sql ||'right outer join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name) + where t1.column_name is null'; + + execute immediate l_sql bulk collect into l_result + using a_current_list,a_cursor_info,a_cursor_info,a_cursor_info; + return l_result; + end; + + function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_cursor_column_tab is l_filtered_set ut_varchar2_list := ut_varchar2_list(); diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 98913531e..09781225d 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -71,7 +71,6 @@ create or replace package ut_compound_data_helper authid definer is function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob; - --TODO : Can this be done better ?? function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, @@ -82,6 +81,9 @@ create or replace package ut_compound_data_helper authid definer is function get_hash(a_data raw, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash; function get_hash(a_data clob, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash; + + function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer :=30) return number; + function columns_hash( a_data_value_cursor ut_data_value_refcursor, a_exclude_xpath varchar2, a_include_xpath varchar2, a_hash_type binary_integer := dbms_crypto.hash_sh1 @@ -90,9 +92,8 @@ create or replace package ut_compound_data_helper authid definer is function is_pk_exists(a_expected_cursor xmltype, a_actual_cursor xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2,a_join_by_xpath varchar2) return tt_missing_pk; - function gen_compare_sql(a_column_info xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2, a_inclusion_type boolean, a_is_negated boolean, - a_unordered boolean, a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=null ) return clob; + function gen_compare_sql(a_column_info xmltype, a_inclusion_type boolean, a_is_negated boolean, a_unordered boolean, + a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob; procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw); @@ -102,6 +103,12 @@ create or replace package ut_compound_data_helper authid definer is function get_rows_diff_count return integer; + function filter_out_cols(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list,a_include boolean := true) + return ut_cursor_column_tab; + + function compare_cursor_to_columns(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list) + return ut_cursor_column_tab; + function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_cursor_column_tab; diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 9b37dd8ea..b1d126df1 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -120,7 +120,7 @@ create or replace type body ut_compound_data_value as -- First tell how many rows are different l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; - + --TODO : Change message when the types not matching if l_diff_row_count > 0 then l_row_diffs := ut_compound_data_helper.get_rows_diff( self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, @@ -200,9 +200,8 @@ create or replace type body ut_compound_data_value as return l_result; end; - member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_unordered boolean, a_inclusion_compare boolean := false, - a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=null ) return integer is + member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean, + a_is_negated boolean, a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return integer is l_diff_id ut_compound_data_helper.t_hash; l_other ut_compound_data_value; @@ -215,15 +214,13 @@ create or replace type body ut_compound_data_value as l_sql_rowcount integer :=0; begin - --TODO : Error on xml when same column is more then once in item data xml.Do we need to cleanup ?? --TODO : Bring diffs row into same place for ref data cursor especially (how we going to do that so we dont break anyval etc) - --TODO : Test binary xml storage (didnt seems to make a diffrence, docker and datafiles layer ??) l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - open l_loop_curs for ut_compound_data_helper.gen_compare_sql(treat(a_other as ut_data_value_refcursor).col_info_desc, a_exclude_xpath, - a_include_xpath, a_join_by_xpath, a_inclusion_compare, a_is_negated, a_unordered, - treat(a_other as ut_data_value_refcursor), a_join_by_list ) using self.data_id,l_other.data_id; + open l_loop_curs for ut_compound_data_helper.gen_compare_sql(treat(a_other as ut_data_value_refcursor).col_info_desc, + a_inclusion_compare, a_is_negated, a_unordered, treat(a_other as ut_data_value_refcursor), + a_join_by_list ) using self.data_id,l_other.data_id; loop fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; exit when l_diff_tab.count = 0; @@ -232,19 +229,17 @@ create or replace type body ut_compound_data_value as end if; l_sql_rowcount := l_sql_rowcount + l_diff_tab.count; - if (ut_utils.gc_diff_max_rows <= l_sql_rowcount and l_max_rows != ut_utils.gc_bc_fetch_limit ) then l_max_rows := ut_utils.gc_bc_fetch_limit; end if; end loop; - --result is OK only if both are same + --result is OK only if both are same if l_sql_rowcount = 0 and ( self.elements_count = l_other.elements_count or a_inclusion_compare )then l_result := 0; else ut_compound_data_helper.set_rows_diff(l_sql_rowcount); l_result := 1; end if; - return l_result; end; diff --git a/source/expectations/data_values/ut_compound_data_value.tps b/source/expectations/data_values/ut_compound_data_value.tps index ce14c494e..771a2f3d2 100644 --- a/source/expectations/data_values/ut_compound_data_value.tps +++ b/source/expectations/data_values/ut_compound_data_value.tps @@ -44,8 +44,7 @@ create or replace type ut_compound_data_value force under ut_data_value( overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return clob, member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2) return integer, - member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2, a_unordered boolean, a_inclusion_compare boolean := false, - a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=null ) return integer + member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean, + a_is_negated boolean, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return integer ) not final not instantiable / diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb index 15f764062..c12162593 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb @@ -18,7 +18,6 @@ create or replace package body ut_curr_usr_compound_helper is function is_sql_compare_allowed(a_type_name varchar2) return boolean is begin --clob/blob/xmltype/object/nestedcursor/nestedtable - if a_type_name IN (g_type_name_map(dbms_sql.blob_type), g_type_name_map(dbms_sql.clob_type), g_type_name_map(dbms_sql.bfile_type)) @@ -53,7 +52,6 @@ create or replace package body ut_curr_usr_compound_helper is l_result ut_key_anyval_pair; l_data_type varchar2(500) := 'unknown datatype'; - --TODO: Review the types in and resolving begin if g_type_name_map.exists(a_desc_rec.col_type) then @@ -245,9 +243,9 @@ create or replace package body ut_curr_usr_compound_helper is return l_result ; end; - function get_column_type(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is + function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is begin - return case when not a_dbms_sql_desc then g_anytype_name_map(a_type_code) else g_type_name_map(a_type_code) end; + return case when a_dbms_sql_desc then g_type_name_map(a_type_code) else g_anytype_name_map(a_type_code) end; end; begin @@ -296,6 +294,9 @@ create or replace package body ut_curr_usr_compound_helper is g_type_name_map( dbms_sql.number_type ) := 'NUMBER'; g_type_name_map( dbms_sql.rowid_type ) := 'ROWID'; g_type_name_map( dbms_sql.urowid_type ) := 'UROWID'; + g_type_name_map( dbms_sql.user_defined_type ) := 'USER_DEFINED_TYPE'; + g_type_name_map( dbms_sql.ref_type ) := 'REF_TYPE'; + end; / diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pks b/source/expectations/data_values/ut_curr_usr_compound_helper.pks index 46404b93c..eb70963ca 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pks +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pks @@ -6,6 +6,7 @@ create or replace package ut_curr_usr_compound_helper authid current_user is function is_collection (a_owner varchar2,a_type_name varchar2) return boolean; + --TODO Depracate once switch fully to type procedure get_columns_info( a_cursor in out nocopy sys_refcursor, a_columns_info out nocopy xmltype, @@ -17,7 +18,7 @@ create or replace package ut_curr_usr_compound_helper authid current_user is function extract_min_col_info(a_full_col_info xmltype) return xmltype; - function get_column_type(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2; + function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2; end; / diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index dbf37b518..e266f818d 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -6,10 +6,9 @@ create or replace type body ut_cursor_column as a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level number := 1, a_col_position number, a_col_type varchar2) is begin - self.parent_name := null; + self.parent_name := a_parent_name; self.hierarchy_level := a_hierarchy_level; self.column_position := a_col_position; - self.is_user_defined := 0; self.column_prec := a_col_prec; self.column_len := a_col_max_len; self.column_scale := a_col_scale; @@ -19,13 +18,15 @@ create or replace type body ut_cursor_column as self.nested_name := case when self.parent_name is null then null else - ut_compound_data_helper.get_hash(utl_raw.cast_to_raw(self.parent_name||'/'||self.column_name)) + '"'||ut_compound_data_helper.get_fixed_size_hash(self.parent_name||self.column_name)||'"' end; self.xml_valid_name := '"'||self.column_name||'"'; self.column_type := a_col_type; self.column_schema := a_col_schema_name; self.is_sql_diffable := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)); - self.is_collection := 0; + self.is_collection := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_collection(a_col_schema_name,a_col_type_name)); + --TODO : fix that as is nasty hardcode + self.is_user_defined := case when lower(self.column_type) = 'user_defined_type' then 1 else 0 end; end; constructor function ut_cursor_column( self in out nocopy ut_cursor_column, diff --git a/source/expectations/data_values/ut_cursor_column.tps b/source/expectations/data_values/ut_cursor_column.tps index 0602b1ceb..dcd352377 100644 --- a/source/expectations/data_values/ut_cursor_column.tps +++ b/source/expectations/data_values/ut_cursor_column.tps @@ -2,7 +2,7 @@ create or replace type ut_cursor_column force authid current_user as object ( parent_name varchar2(100), access_path varchar2(500), - nested_name raw(30), + nested_name varchar2(32), hierarchy_level number, column_position number, xml_valid_name varchar2(100), diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index 2d0b5a67f..016fd2ac5 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -1,65 +1,75 @@ create or replace type body ut_cursor_details as - member function get_anytype_attribute_count(a_anytype anytype) return pls_integer is - l_attribute_typecode pls_integer; - l_schema_name varchar2(32767); - l_version varchar2(32767); - l_type_name varchar2(32767); - l_attributes pls_integer; - l_prec pls_integer; - l_scale pls_integer; - l_len pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - begin - l_attribute_typecode := a_anytype.getinfo(prec => l_prec, - scale => l_scale, - len => l_len, - csid => l_csid, - csfrm => l_csfrm, - schema_name => l_schema_name, - type_name => l_type_name, - version => l_version, - numelems => l_attributes); - return l_attributes; - end; + order member function compare(a_other ut_cursor_details) return integer is + l_diffs integer; + begin + select count(1) into l_diffs + from table(self.cursor_info) a full outer join table(a_other.cursor_info) e + on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and + REPLACE(a.column_type,'VARCHAR','CHAR') = REPLACE(e.column_type,'VARCHAR','CHAR') + and a.column_position = e.column_position ) + where a.column_name is null or e.column_name is null; + return l_diffs; + end; + + member function get_anytype_attribute_count(a_anytype anytype) return pls_integer is + l_attribute_typecode pls_integer; + l_schema_name varchar2(32767); + l_version varchar2(32767); + l_type_name varchar2(32767); + l_attributes pls_integer; + l_prec pls_integer; + l_scale pls_integer; + l_len pls_integer; + l_csid pls_integer; + l_csfrm pls_integer; + begin + l_attribute_typecode := a_anytype.getinfo(prec => l_prec, + scale => l_scale, + len => l_len, + csid => l_csid, + csfrm => l_csfrm, + schema_name => l_schema_name, + type_name => l_type_name, + version => l_version, + numelems => l_attributes); + return l_attributes; + end; member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) - return anytype is - l_anydata anydata; - l_anytype anytype; - l_typecode pls_integer; - - begin - execute immediate 'declare - l_v ' || a_owner || '.' || - a_type_name || '; + return anytype is + l_anydata anydata; + l_anytype anytype; + l_typecode pls_integer; + begin + execute immediate 'declare + l_v ' || a_owner || '.' || + a_type_name || '; begin :anydata := anydata.convertobject(l_v); end;' - using in out l_anydata; + using in out l_anydata; - l_typecode := l_anydata.gettype(l_anytype); + l_typecode := l_anydata.gettype(l_anytype); - return l_anytype; - end; + return l_anytype; + end; constructor function ut_cursor_details(self in out nocopy ut_cursor_details, a_cursor in out nocopy sys_refcursor) - return self as result is - l_cursor_number integer; - l_columns_count pls_integer; - l_columns_desc dbms_sql.desc_tab3; - l_attribute_typecode pls_integer; - l_aname varchar2(32767); - l_prec pls_integer; - l_scale pls_integer; - l_len pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - l_attr_elt_type anytype; - l_anytype anytype; - + return self as result is + l_cursor_number integer; + l_columns_count pls_integer; + l_columns_desc dbms_sql.desc_tab3; + l_attribute_typecode pls_integer; + l_aname varchar2(32767); + l_prec pls_integer; + l_scale pls_integer; + l_len pls_integer; + l_csid pls_integer; + l_csfrm pls_integer; + l_attr_elt_type anytype; + l_anytype anytype; begin self.cursor_info := ut_cursor_column_tab(); l_cursor_number := dbms_sql.to_cursor_number(a_cursor); @@ -79,9 +89,11 @@ create or replace type body ut_cursor_details as null, 1, cur, - ut_curr_usr_compound_helper.get_column_type(l_columns_desc(cur).col_type,false) - ); - if l_columns_desc(cur).col_type = dbms_sql.user_defined_type then + ut_curr_usr_compound_helper.get_column_type_desc(l_columns_desc(cur).col_type,true) + ); + if l_columns_desc(cur).col_type = dbms_sql.user_defined_type + and + not ut_curr_usr_compound_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name) then l_anytype := get_user_defined_type(l_columns_desc(cur).col_schema_name , l_columns_desc(cur).col_type_name ); for i in 1 .. get_anytype_attribute_count(l_anytype) loop l_attribute_typecode := l_anytype.getattreleminfo(pos => i, --First attribute @@ -100,10 +112,10 @@ create or replace type body ut_cursor_details as l_prec, l_scale, l_len, - l_columns_desc(i).col_name, + l_columns_desc(cur).col_name, 2, i, - ut_curr_usr_compound_helper.get_column_type(l_attribute_typecode,true) + ut_curr_usr_compound_helper.get_column_type_desc(l_attribute_typecode,false) ); end loop; end if; diff --git a/source/expectations/data_values/ut_cursor_details.tps b/source/expectations/data_values/ut_cursor_details.tps index 00f03e676..2cb77dade 100644 --- a/source/expectations/data_values/ut_cursor_details.tps +++ b/source/expectations/data_values/ut_cursor_details.tps @@ -1,6 +1,7 @@ create or replace type ut_cursor_details force authid current_user as object ( cursor_info ut_cursor_column_tab, + order member function compare(a_other ut_cursor_details) return integer, member function get_anytype_attribute_count(a_anytype anytype) return pls_integer, member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return anytype, constructor function ut_cursor_details(self in out nocopy ut_cursor_details,a_cursor in out nocopy sys_refcursor) diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index c63583469..9b495221c 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -47,9 +47,7 @@ create or replace type body ut_data_value_refcursor as self.contain_collection); self.elements_count := 0; self.columns_info := ut_curr_usr_compound_helper.extract_min_col_info(self.col_info_desc); - self.cursor_details := ut_cursor_details(l_cursor); - -- We use DBMS_XMLGEN in order to: -- 1) be able to process data in bulks (set of rows) -- 2) be able to influence the ROWSET/ROW tags @@ -226,11 +224,15 @@ create or replace type body ut_data_value_refcursor as return l_result_string; end; - overriding member function compare_implementation (a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean, a_inclusion_compare boolean := false, - a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=null) return integer is + overriding member function compare_implementation (a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean := false, + a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list()) + return integer is l_result integer := 0; l_other ut_data_value_refcursor; + + l_act_pk ut_cursor_column_tab; + l_exp_pk ut_cursor_column_tab; + function is_pk_missing (a_pk_missing_tab ut_compound_data_helper.tt_missing_pk) return integer is begin return case when a_pk_missing_tab.count > 0 then 1 else 0 end; @@ -243,21 +245,19 @@ create or replace type body ut_data_value_refcursor as l_other := treat(a_other as ut_data_value_refcursor); --if we join by key and key is missing fail and report error - if a_join_by_xpath is not null then - l_result := is_pk_missing(ut_compound_data_helper.is_pk_exists(self.key_info, l_other.key_info, a_exclude_xpath, - a_include_xpath,a_join_by_xpath)); + if a_join_by_list.count > 0 then + l_act_pk := ut_compound_data_helper.compare_cursor_to_columns(self.cursor_details.cursor_info ,a_join_by_list); + l_exp_pk := ut_compound_data_helper.compare_cursor_to_columns(l_other.cursor_details.cursor_info,a_join_by_list); + l_result := case when (l_act_pk.count > 0) or (l_exp_pk.count > 0) then 1 else 0 end; end if; - - if l_result = 0 then - --if column names/types are not equal - build a diff of column names and types - if ut_compound_data_helper.columns_hash( self, a_exclude_xpath, a_include_xpath ) - != ut_compound_data_helper.columns_hash( l_other, a_exclude_xpath, a_include_xpath ) - then - l_result := 1; - end if; - l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other, a_exclude_xpath, a_include_xpath, - a_join_by_xpath,a_unordered, a_inclusion_compare, a_is_negated, a_join_by_list); + + if l_result = 0 then + if (self.cursor_details is not null and l_other.cursor_details is not null) and (self.cursor_details != l_other.cursor_details) then + l_result := 1; + end if; + l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other,a_unordered, a_inclusion_compare, + a_is_negated, a_join_by_list); end if; return l_result; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 01b35d745..76deb005f 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -53,9 +53,8 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), overriding member function to_string return varchar2, overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, - overriding member function compare_implementation(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean, a_inclusion_compare boolean := false, - a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=null) return integer, + overriding member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean := false, + a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return integer, overriding member function is_empty return boolean, member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor ) diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index 0e80d9aea..c60d0d48e 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -158,7 +158,7 @@ create or replace type body ut_equal as member function include(a_items varchar2) return ut_equal is l_result ut_equal := self; begin - --TODO : thats poorly done + --TODO : move that logic split into get_include after removed all calls to incl and excl l_result.include_list := l_result.include_list multiset union coalesce(ut_utils.string_to_table(REPLACE(a_items,'|',','),','),ut_varchar2_list()); return l_result; end; @@ -167,7 +167,7 @@ create or replace type body ut_equal as l_result ut_equal := self; l_items ut_varchar2_list := ut_varchar2_list(); begin - --Split exclude into single expressions so we cater for concat operator like | + --TODO : move that logic split into get_include after removed all calls to incl and excl for i in 1..a_items.count loop l_items := l_items multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_items(i),'|',','),','),ut_varchar2_list()); end loop; @@ -178,6 +178,7 @@ create or replace type body ut_equal as member function exclude(a_items varchar2) return ut_equal is l_result ut_equal := self; begin + --TODO : move that logic split into get_include after removed all calls to incl and excl l_result.exclude_list := l_result.exclude_list multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_items,'|',','),','),ut_varchar2_list()); return l_result; end; @@ -186,9 +187,8 @@ create or replace type body ut_equal as l_result ut_equal := self; l_items ut_varchar2_list := ut_varchar2_list(); begin - --Split exclude into single expressions so we cater for concat operator like | + --TODO : move that logic split into get_include after removed all calls to incl and excl for i in 1..a_items.count loop - --TODO : idoiot proof solution for both include and exclude l_items := l_items multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_items(i),'|',','),','),ut_varchar2_list()); end loop; @@ -253,6 +253,12 @@ create or replace type body ut_equal as return ut_utils.to_xpath( coalesce(join_columns, ut_varchar2_list()) ); end; + member function get_join_by_list return ut_varchar2_list is + begin + --TODO : zamiast zmieniac path zmodyfikuj get functions + return ( coalesce(join_columns, ut_varchar2_list()) ); + end; + overriding member function run_matcher(self in out nocopy ut_equal, a_actual ut_data_value) return boolean is l_result boolean; l_actual ut_data_value; @@ -262,8 +268,8 @@ create or replace type body ut_equal as l_result := 0 = treat(self.expected as ut_data_value_anydata).compare_implementation(a_actual, get_exclude_xpath(), get_include_xpath()); elsif self.expected is of (ut_data_value_refcursor) then l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); - l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, get_exclude_xpath(), - get_include_xpath(), get_join_by_xpath(), get_unordered(), false, false, join_on_list ); + l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, + get_unordered(), false, false, get_join_by_list() ); else l_result := equal_with_nulls((self.expected = a_actual), a_actual); end if; diff --git a/source/expectations/matchers/ut_equal.tps b/source/expectations/matchers/ut_equal.tps index 3380306e7..e53fda40b 100644 --- a/source/expectations/matchers/ut_equal.tps +++ b/source/expectations/matchers/ut_equal.tps @@ -72,6 +72,7 @@ create or replace type ut_equal under ut_comparison_matcher( member function get_exclude_xpath return varchar2, member function get_unordered return boolean, member function get_join_by_xpath return varchar2, + member function get_join_by_list return ut_varchar2_list, overriding member function run_matcher(self in out nocopy ut_equal, a_actual ut_data_value) return boolean, overriding member function failure_message(a_actual ut_data_value) return varchar2, overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2 diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index 0e570a719..620f3267d 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -52,11 +52,11 @@ create or replace type body ut_include as l_result boolean; l_actual ut_data_value; begin + --TODO : Join by exclude an include should show differences if self.expected.data_type = a_actual.data_type then l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); - l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, - self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), - true,self.get_inclusion_compare(), self.get_negated(), join_on_list); + l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, + true,self.get_inclusion_compare(), self.get_negated(), self.get_join_by_list()); else l_result := (self as ut_matcher).run_matcher(a_actual); end if; diff --git a/source/expectations/ut_expectation.tpb b/source/expectations/ut_expectation.tpb index 2ad402459..19775c707 100644 --- a/source/expectations/ut_expectation.tpb +++ b/source/expectations/ut_expectation.tpb @@ -38,7 +38,6 @@ create or replace type body ut_expectation as else l_expectation_result := l_matcher.run_matcher_negated( self.actual_data ); end if; - l_expectation_result := coalesce(l_expectation_result,false); l_message := coalesce( l_matcher.error_message( self.actual_data ), l_matcher.failure_message_when_negated( self.actual_data ) ); ut_expectation_processor.add_expectation_result( ut_expectation_result( ut_utils.to_test_result( l_expectation_result ), self.description, l_message ) ); diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index bb5221d4d..83cf23e2f 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2356,39 +2356,99 @@ Diff:% --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + + procedure cursor_not_to_contain + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + open l_expected for select 'TEST' username, -600 user_id from dual; + + open l_actual for select username, user_id from all_users + union all + select 'TEST1' username, -601 user_id from dual; + + --Act + ut3.ut.expect(l_actual).not_to_contain(l_expected); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; - procedure cursor_not_to_contain is + procedure cursor_not_to_include + as + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + open l_expected for select 'TEST' username, -600 user_id from dual; + + open l_actual for select username, user_id from all_users + union all + select 'TEST1' username, -601 user_id from dual; + + --Act + ut3.ut.expect(l_actual).not_to_include(l_expected); + --Asserty + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure cursor_not_to_contain_fail is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); begin --Arrange open l_expected for select 'TEST' username, -600 user_id from dual; open l_actual for select username, user_id from all_users union all - select 'TEST' username, -601 user_id from dual; + select 'TEST' username, -600 user_id from dual; --Act ut3.ut.expect(l_actual).not_to_contain(l_expected); --Assert - ut.expect(expectations.failed_expectations_data()).to_be_empty(); + l_expected_message := q'[%Actual: (refcursor [ count = 18 ])% +%Data-types:% +%VARCHAR2NUMBER% +%Data:% +%was expected not to include:(refcursor [ count = 1 ])% +%Data-types:% +%CHARNUMBER% +%Data:% +%TEST-600%]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); end; - procedure cursor_not_to_include is + procedure cursor_not_to_include_fail is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); begin --Arrange open l_expected for select 'TEST' username, -600 user_id from dual; open l_actual for select username, user_id from all_users union all - select 'TEST' username, -601 user_id from dual; + select 'TEST' username, -600 user_id from dual; --Act ut3.ut.expect(l_actual).not_to_include(l_expected); --Assert - ut.expect(expectations.failed_expectations_data()).to_be_empty(); + l_expected_message := q'[%Actual: (refcursor [ count = 18 ])% +%Data-types:% +%VARCHAR2NUMBER% +%Data:% +%was expected not to include:(refcursor [ count = 1 ])% +%Data-types:% +%CHARNUMBER% +%Data:% +%TEST-600%]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); end; procedure cursor_not_to_contain_joinby is @@ -2410,8 +2470,8 @@ Diff:% l_expected SYS_REFCURSOR; begin --Arrange - open l_actual for select username,user_id from all_users; - open l_expected for select username||'ACT' username ,user_id from all_users where rownum < 5; + open l_actual for select username,rownum * 10 user_id from all_users where rownum < 5; + open l_expected for select username ,rownum user_id from all_users where rownum < 5; --Act ut3.ut.expect(l_actual).not_to_include(l_expected).join_by('USER_ID'); diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index e70bb8cdf..f6e3de27c 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -380,7 +380,13 @@ create or replace package test_expectations_cursor is procedure cursor_not_to_contain; --%test( Cursor not to include data from another cursor) - procedure cursor_not_to_include; + procedure cursor_not_to_include; + + --%test( Cursor fail not to contains data from another cursor) + procedure cursor_not_to_contain_fail; + + --%test( Cursor fail not to include data from another cursor) + procedure cursor_not_to_include_fail; --%test( Cursor not contains data from another cursor with joinby clause) procedure cursor_not_to_contain_joinby; From e4043b5cc95db4bed05a94d244d3956b64df1234 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Mon, 19 Nov 2018 07:14:28 +0000 Subject: [PATCH 54/83] Updates to include nested an collections --- .../expectations/data_values/ut_compound_data_helper.pkb | 3 +-- source/expectations/data_values/ut_cursor_column.tpb | 9 +++++++-- source/expectations/data_values/ut_cursor_column.tps | 2 +- test/core/expectations/test_expectations_cursor.pkb | 4 ++-- 4 files changed, 11 insertions(+), 7 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 69eca4f3d..d61140732 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -543,7 +543,7 @@ create or replace package body ut_compound_data_helper is --TODO : Collection is intersting exmaple that we probably has to extract full xml and hash it. ut_utils.append_to_clob(a_partition_stmt,', row_number() over (partition by '); for i in 1..l_cursor_info.count loop - if l_cursor_info(i).is_user_defined = 0 then + if l_cursor_info(i).has_nested_col = 0 then l_col_name := case when l_cursor_info(i).parent_name is null then l_cursor_info(i).xml_valid_name else @@ -690,7 +690,6 @@ create or replace package body ut_compound_data_helper is end if; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - --dbms_output.put_line(l_compare_sql); return l_compare_sql; end; diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index e266f818d..6223ea9a4 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -23,10 +23,15 @@ create or replace type body ut_cursor_column as self.xml_valid_name := '"'||self.column_name||'"'; self.column_type := a_col_type; self.column_schema := a_col_schema_name; - self.is_sql_diffable := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)); + self.is_sql_diffable := case when lower(self.column_type) = 'user_defined_type' then + 0 + else + ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)) + end; + --TODO : Part of the constructor same as has nested ?? self.is_collection := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_collection(a_col_schema_name,a_col_type_name)); --TODO : fix that as is nasty hardcode - self.is_user_defined := case when lower(self.column_type) = 'user_defined_type' then 1 else 0 end; + self.has_nested_col := case when lower(self.column_type) = 'user_defined_type' and self.is_collection = 0 then 1 else 0 end; end; constructor function ut_cursor_column( self in out nocopy ut_cursor_column, diff --git a/source/expectations/data_values/ut_cursor_column.tps b/source/expectations/data_values/ut_cursor_column.tps index dcd352377..c15e73458 100644 --- a/source/expectations/data_values/ut_cursor_column.tps +++ b/source/expectations/data_values/ut_cursor_column.tps @@ -2,6 +2,7 @@ create or replace type ut_cursor_column force authid current_user as object ( parent_name varchar2(100), access_path varchar2(500), + has_nested_col number(1,0), nested_name varchar2(32), hierarchy_level number, column_position number, @@ -15,7 +16,6 @@ create or replace type ut_cursor_column force authid current_user as object column_scale integer, is_sql_diffable number(1, 0), is_collection number(1, 0), - is_user_defined number(1, 0), member procedure init(self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 83cf23e2f..d37ad7572 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -1542,9 +1542,9 @@ Diff:% ut3.ut.expect(l_actual).to_equal(l_expected).unordered; l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 3 ]% Diff:% -Rows: [ 5 differences 1 -%Extra: 1Something 11% +Rows: [ 5 differences% %Extra: 2Something 22% +%Extra: 1Something 11% %Missing: 1Somethings 11% %Missing: 2Somethings 22% %Missing: 3Somethings 33%]'; From 6cb5fe7d629889185ff3fae6db44040b912080d2 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Tue, 20 Nov 2018 00:07:48 +0000 Subject: [PATCH 55/83] Further deprecation of Xpath --- .../data_values/ut_compound_data_helper.pkb | 137 ++++++++---------- .../data_values/ut_compound_data_helper.pks | 12 +- .../data_values/ut_compound_data_value.tpb | 8 +- .../ut_curr_usr_compound_helper.pkb | 3 +- .../data_values/ut_cursor_column.tpb | 5 + .../data_values/ut_data_value_refcursor.tpb | 40 +++-- .../data_values/ut_data_value_refcursor.tps | 3 +- source/expectations/matchers/ut_equal.tpb | 14 +- source/expectations/matchers/ut_include.tpb | 14 +- .../expectations/test_expectations_cursor.pkb | 47 ++---- .../expectations/test_expectations_cursor.pks | 3 - 11 files changed, 141 insertions(+), 145 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index d61140732..61591e383 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -85,81 +85,45 @@ create or replace package body ut_compound_data_helper is end if; return l_filter; end; - - function get_columns_diff( - a_expected xmltype, a_actual xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2 - ) return tt_column_diffs is + + function get_columns_diff(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab) + return tt_column_diffs is l_column_filter varchar2(32767); l_sql varchar2(32767); l_results tt_column_diffs; begin - l_column_filter := get_columns_row_filter(a_exclude_xpath, a_include_xpath); - --CARDINALITY hints added to address issue: https://github.com/utPLSQL/utPLSQL/issues/752 - l_sql := q'[ - with - expected_cols as ( select :a_expected as item_data from dual ), - actual_cols as ( select :a_actual as item_data from dual ), - expected_cols_info as ( - select e.*, - replace(expected_type,'VARCHAR2','CHAR') expected_type_compare - from ( - select /*+ CARDINALITY(xt 100) */ - rownum expected_pos, - xt.name expected_name, - xt.type expected_type - from (select ]'||l_column_filter||q'[ from expected_cols ucd) x, - xmltable( - '/ROW/*' - passing x.item_data - columns - name varchar2(4000) PATH '@xml_valid_name', - type varchar2(4000) PATH '/' - ) xt - ) e - ), - actual_cols_info as ( - select a.*, - replace(actual_type,'VARCHAR2','CHAR') actual_type_compare - from (select /*+ CARDINALITY(xt 100) */ - rownum actual_pos, - xt.name actual_name, - xt.type actual_type - from (select ]'||l_column_filter||q'[ from actual_cols ucd) x, - xmltable('/ROW/*' - passing x.item_data - columns - name varchar2(4000) path '@xml_valid_name', - type varchar2(4000) path '/' - ) xt - ) a - ), - joined_cols as ( - select e.*, a.*, - row_number() over(partition by case when actual_pos + expected_pos is not null then 1 end order by actual_pos) a_pos_nn, - row_number() over(partition by case when actual_pos + expected_pos is not null then 1 end order by expected_pos) e_pos_nn - from expected_cols_info e - full outer join actual_cols_info a on e.expected_name = a.actual_name - ) + with + expected_cols as + (select access_path exp_column_name,column_position exp_col_pos, + replace(column_type,'VARCHAR2','CHAR') exp_col_type_compare, column_type exp_col_type + from table(a_expected)), + actual_cols as + (select access_path act_column_name,column_position act_col_pos, + replace(column_type,'VARCHAR2','CHAR') act_col_type_compare, column_type act_col_type + from table(a_actual)), + joined_cols as + (select e.*,a.*, + row_number() over(partition by case when a.act_col_pos + e.exp_col_pos is not null then 1 end order by a.act_col_pos) a_pos_nn, + row_number() over(partition by case when a.act_col_pos + e.exp_col_pos is not null then 1 end order by e.exp_col_pos) e_pos_nn + from expected_cols e + full outer join actual_cols a on e.exp_column_name = a.act_column_name) select case - when expected_pos is null and actual_pos is not null then '+' - when expected_pos is not null and actual_pos is null then '-' - when expected_type_compare != actual_type_compare then 't' + when exp_col_pos is null and act_col_pos is not null then '+' + when exp_col_pos is not null and act_col_pos is null then '-' + when exp_col_type_compare != act_col_type_compare then 't' else 'p' end as diff_type, - expected_name, expected_type, expected_pos, - actual_name, actual_type, actual_pos + exp_column_name, exp_col_type, exp_col_pos, + act_column_name, act_col_type, act_col_pos + bulk collect into l_results from joined_cols --column is unexpected (extra) or missing - where actual_pos is null or expected_pos is null + where act_col_pos is null or exp_col_pos is null --column type is not matching (except CHAR/VARCHAR2) - or actual_type_compare != expected_type_compare + or act_col_type_compare != exp_col_type_compare --column position is not matching (both when excluded extra/missing columns as well as when they are included) - or (a_pos_nn != e_pos_nn and expected_pos != actual_pos) - order by expected_pos, actual_pos]'; - execute immediate l_sql - bulk collect into l_results - using a_expected, a_actual, a_exclude_xpath, a_include_xpath, a_exclude_xpath, a_include_xpath; - + or (a_pos_nn != e_pos_nn and exp_col_pos != act_col_pos) + order by exp_col_pos, act_col_pos; return l_results; end; @@ -690,6 +654,7 @@ create or replace package body ut_compound_data_helper is end if; ut_utils.append_to_clob(l_compare_sql,l_temp_string); + dbms_output.put_line(l_compare_sql); return l_compare_sql; end; @@ -735,12 +700,8 @@ create or replace package body ut_compound_data_helper is select lev,column_name,parent_name from hier), t1(column_name, parent_name) AS ( select column_name,parent_name from table(:a_cursor_info) where parent_name is null - union all - select t2.column_name,t2.parent_name from table(:a_cursor_info) t2, t1 where t2.parent_name = t1.column_name) - select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name, i.column_prec,i.column_scale,i.column_len, i.parent_name, - i.hierarchy_level,i.column_position, i.column_type) - from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name) - ]'; + union all + select t2.column_name,t2.parent_name from table(:a_cursor_info) t2, t1 where t2.parent_name = t1.column_name)]'; begin return l_sql; end; @@ -750,10 +711,13 @@ create or replace package body ut_compound_data_helper is l_sql varchar2(32767) := get_cursor_vs_list_sql; l_result ut_cursor_column_tab := ut_cursor_column_tab(); begin + l_sql := l_sql || q'[select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name, i.column_prec,i.column_scale,i.column_len, i.parent_name, + i.hierarchy_level,i.column_position, i.column_type) + from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name)]'; if a_include then l_sql := l_sql || ' join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name)'; else - l_sql := l_sql ||'left outer join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name) + l_sql := l_sql ||' left outer join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name) where c.column_name is null'; end if; @@ -764,10 +728,12 @@ create or replace package body ut_compound_data_helper is end; function compare_cursor_to_columns(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list) - return ut_cursor_column_tab is + return ut_varchar2_list is l_sql varchar2(32767) := get_cursor_vs_list_sql; - l_result ut_cursor_column_tab := ut_cursor_column_tab(); + l_result ut_varchar2_list := ut_varchar2_list(); begin + l_sql := l_sql || q'[select c.parent_name || case when c.parent_name is null then null else '/' end ||c.column_name + from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name)]'; l_sql := l_sql ||'right outer join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name) where t1.column_name is null'; @@ -775,7 +741,22 @@ create or replace package body ut_compound_data_helper is using a_current_list,a_cursor_info,a_cursor_info,a_cursor_info; return l_result; end; - + + function get_missing_pk(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab, a_current_list ut_varchar2_list) + return tt_missing_pk is + l_actual ut_varchar2_list := coalesce(compare_cursor_to_columns(a_actual,a_current_list),ut_varchar2_list()); + l_expected ut_varchar2_list := coalesce(compare_cursor_to_columns(a_expected,a_current_list),ut_varchar2_list()); + l_missing_pk tt_missing_pk; + begin + select name,type + bulk collect into l_missing_pk + from + (select act.column_value name, 'e' type from table(l_expected) act + union all + select exp.column_value name, 'a' type from table(l_actual) exp) + order by type desc,name; + return l_missing_pk; + end; function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_cursor_column_tab is @@ -819,5 +800,13 @@ create or replace package body ut_compound_data_helper is return l_result; end; + function contains_collection (a_cursor_info ut_cursor_column_tab) return number is + l_collection_elements number; + begin + select count(1) into l_collection_elements from + table(a_cursor_info) c where c.is_collection = 1; + return l_collection_elements; + end; + end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 09781225d..f2b31f82e 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -65,9 +65,8 @@ create or replace package ut_compound_data_helper authid definer is a_table_alias varchar2 := 'ucd', a_column_alias varchar2 := 'item_data' ) return varchar2; - function get_columns_diff( - a_expected xmltype, a_actual xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2 - ) return tt_column_diffs; + function get_columns_diff(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab) + return tt_column_diffs; function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob; @@ -107,10 +106,15 @@ create or replace package ut_compound_data_helper authid definer is return ut_cursor_column_tab; function compare_cursor_to_columns(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list) - return ut_cursor_column_tab; + return ut_varchar2_list; + + function get_missing_pk(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab, a_current_list ut_varchar2_list) + return tt_missing_pk; function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_cursor_column_tab; + function contains_collection (a_cursor_info ut_cursor_column_tab) return number; + end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index b1d126df1..12396c756 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -79,6 +79,7 @@ create or replace type body ut_compound_data_value as return l_result_string; end; + -- TODO : Rework to exclude xpath member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean) return clob is c_max_rows integer := ut_utils.gc_diff_max_rows; @@ -128,15 +129,16 @@ create or replace type body ut_compound_data_value as l_message := chr(10) ||'Rows: [ ' || l_diff_row_count ||' differences' || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end - ||' ]' || chr(10) - || case when l_row_diffs.count = 0 - then ' All rows are different as the columns are not matching.' end; + ||' ]'||chr(10)|| case when l_row_diffs.count = 0 then ' All rows are different as the columns are not matching.' else null end; ut_utils.append_to_clob( l_result, l_message ); for i in 1 .. l_row_diffs.count loop l_results.extend; l_results(l_results.last) := get_diff_message(l_row_diffs(i),a_unordered); end loop; ut_utils.append_to_clob(l_result,l_results); + else + l_message:= chr(10)||'Rows: [ all different ]'||chr(10)||' All rows are different as the columns are not matching.'; + ut_utils.append_to_clob( l_result, l_message ); end if; return l_result; end; diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb index c12162593..f829a9c0a 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb @@ -20,7 +20,8 @@ create or replace package body ut_curr_usr_compound_helper is --clob/blob/xmltype/object/nestedcursor/nestedtable if a_type_name IN (g_type_name_map(dbms_sql.blob_type), g_type_name_map(dbms_sql.clob_type), - g_type_name_map(dbms_sql.bfile_type)) + g_type_name_map(dbms_sql.bfile_type), + g_anytype_name_map(dbms_types.typecode_namedcollection)) then return false; else diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index 6223ea9a4..b9216ec4d 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -34,6 +34,11 @@ create or replace type body ut_cursor_column as self.has_nested_col := case when lower(self.column_type) = 'user_defined_type' and self.is_collection = 0 then 1 else 0 end; end; + --TODO : Scenarios : + --namedcollection xmltype getclobhash + --collection xml type get clob hash + -- user defined type + constructor function ut_cursor_column( self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 9b495221c..2d12fe9f7 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -116,14 +116,17 @@ create or replace type body ut_data_value_refcursor as return l_result_string; end; - overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2 is + member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, + a_unordered boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return varchar2 is l_result clob; l_results ut_utils.t_clob_tab := ut_utils.t_clob_tab(); l_result_string varchar2(32767); l_actual ut_data_value_refcursor; l_column_diffs ut_compound_data_helper.tt_column_diffs := ut_compound_data_helper.tt_column_diffs(); l_exclude_xpath varchar2(32767) := a_exclude_xpath; + l_missing_pk ut_compound_data_helper.tt_missing_pk := ut_compound_data_helper.tt_missing_pk(); + l_col_diffs ut_compound_data_helper.tt_column_diffs := ut_compound_data_helper.tt_column_diffs(); function get_col_diff_text(a_col ut_compound_data_helper.t_column_diffs) return varchar2 is begin @@ -143,7 +146,6 @@ create or replace type body ut_data_value_refcursor as function get_missing_key_message(a_missing_keys ut_compound_data_helper.t_missing_pk) return varchar2 is l_message varchar2(200); begin - if a_missing_keys.diff_type = 'a' then l_message := ' Join key '||a_missing_keys.missingxpath||' does not exists in actual'; elsif a_missing_keys.diff_type = 'e' then @@ -184,7 +186,7 @@ create or replace type body ut_data_value_refcursor as --diff columns if not self.is_null and not l_actual.is_null then - l_column_diffs := ut_compound_data_helper.get_columns_diff(self.columns_info, l_actual.columns_info, a_exclude_xpath, a_include_xpath); + l_column_diffs := ut_compound_data_helper.get_columns_diff(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info); if l_column_diffs.count > 0 then ut_utils.append_to_clob(l_result,chr(10) || 'Columns:' || chr(10)); @@ -199,8 +201,8 @@ create or replace type body ut_data_value_refcursor as end if; --check for missing pk - if (a_join_by_xpath is not null) then - l_missing_pk := ut_compound_data_helper.is_pk_exists(self.key_info, l_actual.key_info, a_exclude_xpath, a_include_xpath,a_join_by_xpath); + if a_join_by_list.count > 0 then + l_missing_pk := ut_compound_data_helper.get_missing_pk(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info,a_join_by_list); end if; --diff rows and row elements if the pk is not missing @@ -213,7 +215,8 @@ create or replace type body ut_data_value_refcursor as ut_utils.append_to_clob(l_result, get_missing_key_message(l_missing_pk(i))|| chr(10)); end loop; - if ut_utils.int_to_boolean(self.contain_collection) or ut_utils.int_to_boolean(l_actual.contain_collection) then + if ut_compound_data_helper.contains_collection(self.cursor_details.cursor_info) > 0 + or ut_compound_data_helper.contains_collection(l_actual.cursor_details.cursor_info) > 0 then ut_utils.append_to_clob(l_result,' Please make sure that your join clause is not refferring to collection element'|| chr(10)); end if; @@ -228,36 +231,29 @@ create or replace type body ut_data_value_refcursor as a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return integer is l_result integer := 0; - l_other ut_data_value_refcursor; - - l_act_pk ut_cursor_column_tab; - l_exp_pk ut_cursor_column_tab; + l_actual ut_data_value_refcursor; + + l_pk_missing_tab ut_compound_data_helper.tt_missing_pk; - function is_pk_missing (a_pk_missing_tab ut_compound_data_helper.tt_missing_pk) return integer is - begin - return case when a_pk_missing_tab.count > 0 then 1 else 0 end; - end; begin if not a_other is of (ut_data_value_refcursor) then raise value_error; end if; - l_other := treat(a_other as ut_data_value_refcursor); + l_actual := treat(a_other as ut_data_value_refcursor); --if we join by key and key is missing fail and report error if a_join_by_list.count > 0 then - l_act_pk := ut_compound_data_helper.compare_cursor_to_columns(self.cursor_details.cursor_info ,a_join_by_list); - l_exp_pk := ut_compound_data_helper.compare_cursor_to_columns(l_other.cursor_details.cursor_info,a_join_by_list); - l_result := case when (l_act_pk.count > 0) or (l_exp_pk.count > 0) then 1 else 0 end; + l_pk_missing_tab := ut_compound_data_helper.get_missing_pk(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info,a_join_by_list); + l_result := case when (l_pk_missing_tab.count > 0) then 1 else 0 end; end if; - if l_result = 0 then - if (self.cursor_details is not null and l_other.cursor_details is not null) and (self.cursor_details != l_other.cursor_details) then + if (self.cursor_details is not null and l_actual.cursor_details is not null) and (self.cursor_details != l_actual.cursor_details) then l_result := 1; - end if; + end if; l_result := l_result + (self as ut_compound_data_value).compare_implementation(a_other,a_unordered, a_inclusion_compare, - a_is_negated, a_join_by_list); + a_is_negated, a_join_by_list); end if; return l_result; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 76deb005f..ca740f191 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -52,7 +52,8 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) return self as result, member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), overriding member function to_string return varchar2, - overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2, + member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false + ,a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return varchar2, overriding member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return integer, overriding member function is_empty return boolean, diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index c60d0d48e..489e9f41f 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -282,11 +282,19 @@ create or replace type body ut_equal as overriding member function failure_message(a_actual ut_data_value) return varchar2 is l_result varchar2(32767); + l_actual ut_data_value; begin if self.expected.data_type = a_actual.data_type and self.expected.is_diffable then - l_result := - 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() - || chr(10) || 'Diff:' || expected.diff(a_actual, get_exclude_xpath(), get_include_xpath(), get_join_by_xpath(), get_unordered()); + if self.expected is of (ut_data_value_refcursor) then + l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); + l_result := + 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() + || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).diff(l_actual, get_exclude_xpath(), get_include_xpath(), get_join_by_xpath(), get_unordered(),get_join_by_list()); + else + l_result := + 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() + || chr(10) || 'Diff:' || expected.diff(a_actual, get_exclude_xpath(), get_include_xpath(), get_join_by_xpath(), get_unordered()); + end if; else l_result := (self as ut_matcher).failure_message(a_actual) || ': '|| self.expected.to_string_report(); end if; diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index 620f3267d..696e89a14 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -65,11 +65,19 @@ create or replace type body ut_include as overriding member function failure_message(a_actual ut_data_value) return varchar2 is l_result varchar2(32767); + l_actual ut_data_value; begin if self.expected.data_type = a_actual.data_type and self.expected.is_diffable then - l_result := - 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() - || chr(10) || 'Diff:' || expected.diff(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), true); + if self.expected is of (ut_data_value_refcursor) then + l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); + l_result := + 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() + || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(self.exclude_list, self.include_list).diff(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), true); + else + l_result := + 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() + || chr(10) || 'Diff:' || expected.diff(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), true); + end if; else l_result := (self as ut_matcher).failure_message(a_actual) || ': '|| self.expected.to_string_report(); end if; diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index d37ad7572..41fbaa3c4 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -481,25 +481,6 @@ create or replace package body test_expectations_cursor is ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; - procedure include_columns_xpath_invalid - as - l_actual SYS_REFCURSOR; - l_expected SYS_REFCURSOR; - begin - --Arrange - open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 4; - open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; - begin - --Act - ut3.ut.expect(l_actual).to_equal(l_expected).include('/ROW/RN,\\//A_Column,//SOME_COL'); - --Assert - ut.fail('Expected exception but nothing was raised'); - exception - when others then - ut.expect(sqlcode).to_be_between(-31013,-31011); - end; - end; - procedure include_columns_xpath as l_actual sys_refcursor; @@ -617,7 +598,9 @@ Rows: [ 1 differences ] l_expected_message := q'[Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ] Diff: Columns: - Column data-type is invalid. Expected: NUMBER, actual: VARCHAR2.]'; + Column data-type is invalid. Expected: NUMBER, actual: VARCHAR2. +Rows: [ all different ] + All rows are different as the columns are not matching.]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -663,7 +646,9 @@ Diff: Columns: Column is misplaced. Expected position: 2, actual position: 4. Column is misplaced. Expected position: 3, actual position: 2. - Column is misplaced. Expected position: 4, actual position: 3.]'; + Column is misplaced. Expected position: 4, actual position: 3. +Rows: [ all different ] + All rows are different as the columns are not matching.]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -990,15 +975,15 @@ Rows: [ 4 differences ] --Act ut3.ut.expect(l_actual).to_equal(l_expected); - l_expected_message := q'[Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ]% -Diff:% -Columns:% - Column [data-type: NUMBER] is missing. Expected column position: 1.% - Column [data-type: NUMBER] is missing. Expected column position: 2.% - Column <%1%> [position: 1, data-type: CHAR] is not expected in results.% - Column <%2%> [position: 2, data-type: CHAR] is not expected in results.% -Rows: [ 2 differences ]% - All rows are different as the columns are not matching.%]'; + l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ] +%Diff: +%Columns: +%Column [data-type: NUMBER] is missing. Expected column position: 1. +%Column [data-type: NUMBER] is missing. Expected column position: 2. +%Column <1> [position: 1, data-type: CHAR] is not expected in results. +%Column <2> [position: 2, data-type: CHAR] is not expected in results. +%Rows: [ all different ] +%All rows are different as the columns are not matching.]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -1026,7 +1011,7 @@ Rows: [ 2 differences ]% begin --Arrange open l_actual for select rownum as rn, 'a', 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 4; - open l_expected for select rownum as rn, 'a', 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + open l_expected for select rownum as rn, 'a', 'd' as A_COLUMN, 'c' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; begin --Act ut3.ut.expect(l_actual).to_equal(l_expected).include(q'!/ROW/RN,'a',//SOME_COL!'); diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index f6e3de27c..0bd3e81d5 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -107,9 +107,6 @@ create or replace package test_expectations_cursor is --%test(Comma separated list of columns to include is case sensitive) procedure include_columns_as_csv; - --%test(Include columns fails on invalid XPath) - procedure include_columns_xpath_invalid; - --%test(Include columns by XPath is case sensitive) procedure include_columns_xpath; From 1356f39ef70082d9b7e3933834c40dd869099d1b Mon Sep 17 00:00:00 2001 From: lwasylow Date: Tue, 20 Nov 2018 20:42:18 +0000 Subject: [PATCH 56/83] Update to cursor comparision --- .../data_values/ut_compound_data_helper.pkb | 27 ++++++++++++++----- .../data_values/ut_compound_data_value.tpb | 19 ++++++------- .../ut_curr_usr_compound_helper.pkb | 17 ++++++++---- .../ut_curr_usr_compound_helper.pks | 2 +- .../data_values/ut_cursor_column.tpb | 12 ++++----- .../data_values/ut_cursor_column.tps | 8 +++--- .../data_values/ut_cursor_details.tpb | 21 +++++++++------ .../data_values/ut_data_value_refcursor.tpb | 1 + source/expectations/matchers/ut_include.tpb | 1 + source/expectations/ut_expectation.tpb | 7 ++--- .../expectations/test_expectations_cursor.pkb | 4 +-- 11 files changed, 72 insertions(+), 47 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 61591e383..139e3fb8e 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -444,6 +444,7 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(a_equal_stmt,l_sql_stmt); end; + --TODO : Scenario where join by is on whole type not a column of type e.g. NESTEDTABLE procedure generate_partition_stmt(a_data_info ut_cursor_column, a_partition_stmt in out nocopy clob,a_pk_table in ut_varchar2_list,a_col_name in varchar2) is l_alias varchar2(10) := 'ucd.'; l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); @@ -486,10 +487,20 @@ create or replace package body ut_compound_data_helper is begin if a_data_info.is_sql_diffable = 0 then l_col_type := 'XMLTYPE'; + --TODO : Is it right to use timestamp ? elsif a_data_info.is_sql_diffable = 1 and a_data_info.column_type = 'DATE' then l_col_type := 'TIMESTAMP'; + elsif a_data_info.is_sql_diffable = 1 and a_data_info.column_type in ('TIMESTAMP','TIMESTAMP WITH TIME ZONE') then + l_col_type := a_data_info.column_type; + --TODO : Oracle bug : https://community.oracle.com/thread/1957521 + elsif a_data_info.is_sql_diffable = 1 and a_data_info.column_type = 'TIMESTAMP WITH LOCAL TIME ZONE' then + l_col_type := 'VARCHAR2(50)'; + elsif a_data_info.is_sql_diffable = 1 and a_data_info.column_type in ('INTERVAL DAY TO SECOND','INTERVAL YEAR TO MONTH') then + l_col_type := a_data_info.column_type; else - l_col_type := a_data_info.column_type||case when a_data_info.column_len is not null then '('||a_data_info.column_len||')' else null end; + l_col_type := a_data_info.column_type||case when a_data_info.column_len is not null then + '('||a_data_info.column_len||')' + else null end; end if; l_sql_stmt := ' '||a_col_name||' '||l_col_type||q'[ PATH ']'||a_data_info.access_path||q'[',]'; ut_utils.append_to_clob(a_sql_stmt, l_sql_stmt); @@ -654,7 +665,7 @@ create or replace package body ut_compound_data_helper is end if; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - dbms_output.put_line(l_compare_sql); + --dbms_output.put_line(l_compare_sql); return l_compare_sql; end; @@ -689,15 +700,17 @@ create or replace package body ut_compound_data_helper is l_sql varchar2(32767) := q'[with sorted as - (select r_num,regexp_substr(t.column_value, '[^/]+', 1, commas.column_value) as colval,commas.column_value lev + (select r_num,regexp_substr(t.column_value, '[^/]+', 1, commas.column_value) as colval,commas.column_value lev, + t.column_value access_path from (select row_number() over(order by 1) r_num, column_value from ((table(:a_current_list)))) t, table(cast(multiset (select level from dual connect by level <= length(regexp_replace(t.column_value,'[^/]+')) + 1) as sys.odcinumberlist)) commas order by r_num,lev), hier as - (select r_num,lev,colval column_name,lag(colval, 1) over(partition by r_num order by lev) parent_name from sorted), + (select r_num,lev,colval column_name,lag(colval, 1) over(partition by r_num order by lev) parent_name , access_path + from sorted), constructed as ( - select lev,column_name,parent_name from hier), + select lev,column_name,parent_name,access_path from hier), t1(column_name, parent_name) AS ( select column_name,parent_name from table(:a_cursor_info) where parent_name is null union all @@ -712,7 +725,7 @@ create or replace package body ut_compound_data_helper is l_result ut_cursor_column_tab := ut_cursor_column_tab(); begin l_sql := l_sql || q'[select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name, i.column_prec,i.column_scale,i.column_len, i.parent_name, - i.hierarchy_level,i.column_position, i.column_type) + i.hierarchy_level,i.column_position, i.column_type, i.is_collection) from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name)]'; if a_include then l_sql := l_sql || ' join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name)'; @@ -732,7 +745,7 @@ create or replace package body ut_compound_data_helper is l_sql varchar2(32767) := get_cursor_vs_list_sql; l_result ut_varchar2_list := ut_varchar2_list(); begin - l_sql := l_sql || q'[select c.parent_name || case when c.parent_name is null then null else '/' end ||c.column_name + l_sql := l_sql || q'[select c.access_path from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name)]'; l_sql := l_sql ||'right outer join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name) where t1.column_name is null'; diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 12396c756..8db8071df 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -229,20 +229,21 @@ create or replace type body ut_compound_data_value as if (ut_utils.gc_diff_max_rows > l_sql_rowcount ) then ut_compound_data_helper.insert_diffs_result(l_diff_tab,l_diff_id); end if; - l_sql_rowcount := l_sql_rowcount + l_diff_tab.count; if (ut_utils.gc_diff_max_rows <= l_sql_rowcount and l_max_rows != ut_utils.gc_bc_fetch_limit ) then l_max_rows := ut_utils.gc_bc_fetch_limit; end if; - end loop; + end loop; + + ut_compound_data_helper.set_rows_diff(l_sql_rowcount); --result is OK only if both are same - if l_sql_rowcount = 0 and ( self.elements_count = l_other.elements_count or a_inclusion_compare )then - l_result := 0; - else - ut_compound_data_helper.set_rows_diff(l_sql_rowcount); - l_result := 1; - end if; - return l_result; + if l_sql_rowcount = 0 and ( self.elements_count = l_other.elements_count or a_inclusion_compare )then + l_result := 0; + else + l_result := 1; + end if; + + return l_result; end; diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb index f829a9c0a..8c7b53c92 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb @@ -34,15 +34,22 @@ create or replace package body ut_curr_usr_compound_helper is return ut_utils.boolean_to_int(is_sql_compare_allowed(a_type_name)); end; - function is_collection (a_owner varchar2,a_type_name varchar2) return boolean is + function is_collection (a_owner varchar2,a_type_name varchar2, a_anytype_code in integer :=null) return boolean is l_type_view varchar2(200) := ut_metadata.get_dba_view('dba_types'); l_typecode varchar2(100); begin - execute immediate 'select typecode from '||l_type_view ||' - where owner = :owner and type_name = :typename' - into l_typecode using a_owner,a_type_name; - return l_typecode = 'COLLECTION'; + if a_anytype_code is null then + + execute immediate 'select typecode from '||l_type_view ||' + where owner = :owner and type_name = :typename' + into l_typecode using a_owner,a_type_name; + + return l_typecode = 'COLLECTION'; + else + return a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection); + end if; + exception when no_data_found then return false; diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pks b/source/expectations/data_values/ut_curr_usr_compound_helper.pks index eb70963ca..71427b686 100644 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pks +++ b/source/expectations/data_values/ut_curr_usr_compound_helper.pks @@ -4,7 +4,7 @@ create or replace package ut_curr_usr_compound_helper authid current_user is function is_sql_compare_int(a_type_name varchar2) return integer; - function is_collection (a_owner varchar2,a_type_name varchar2) return boolean; + function is_collection (a_owner varchar2,a_type_name varchar2, a_anytype_code in integer :=null) return boolean; --TODO Depracate once switch fully to type procedure get_columns_info( diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index b9216ec4d..1c650708e 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -3,8 +3,8 @@ create or replace type body ut_cursor_column as member procedure init(self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level number := 1, - a_col_position number, a_col_type varchar2) is + a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_position integer, a_col_type varchar2, a_collection integer) is begin self.parent_name := a_parent_name; self.hierarchy_level := a_hierarchy_level; @@ -29,7 +29,7 @@ create or replace type body ut_cursor_column as ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)) end; --TODO : Part of the constructor same as has nested ?? - self.is_collection := ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_collection(a_col_schema_name,a_col_type_name)); + self.is_collection := a_collection; --TODO : fix that as is nasty hardcode self.has_nested_col := case when lower(self.column_type) = 'user_defined_type' and self.is_collection = 0 then 1 else 0 end; end; @@ -42,11 +42,11 @@ create or replace type body ut_cursor_column as constructor function ut_cursor_column( self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level number := 1, - a_col_position number, a_col_type in varchar2) return self as result is + a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_position integer, a_col_type in varchar2, a_collection integer) return self as result is begin init(a_col_name, a_col_schema_name, a_col_type_name, a_col_prec, - a_col_scale, a_col_max_len, a_parent_name,a_hierarchy_level, a_col_position, a_col_type); + a_col_scale, a_col_max_len, a_parent_name,a_hierarchy_level, a_col_position, a_col_type, a_collection); return; end; end; diff --git a/source/expectations/data_values/ut_cursor_column.tps b/source/expectations/data_values/ut_cursor_column.tps index c15e73458..82ec96f02 100644 --- a/source/expectations/data_values/ut_cursor_column.tps +++ b/source/expectations/data_values/ut_cursor_column.tps @@ -20,14 +20,14 @@ create or replace type ut_cursor_column force authid current_user as object member procedure init(self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level number := 1, - a_col_position number, a_col_type in varchar2), + a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_position integer, a_col_type in varchar2, a_collection integer), constructor function ut_cursor_column( self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level number := 1, - a_col_position number, a_col_type in varchar2) + a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_position integer, a_col_type in varchar2, a_collection integer) return self as result ) / diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index 016fd2ac5..7323d7e13 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -3,12 +3,14 @@ create or replace type body ut_cursor_details as order member function compare(a_other ut_cursor_details) return integer is l_diffs integer; begin + select count(1) into l_diffs from table(self.cursor_info) a full outer join table(a_other.cursor_info) e on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and - REPLACE(a.column_type,'VARCHAR','CHAR') = REPLACE(e.column_type,'VARCHAR','CHAR') + REPLACE(a.column_type,'VARCHAR2','CHAR') = REPLACE(e.column_type,'VARCHAR2','CHAR') and a.column_position = e.column_position ) where a.column_name is null or e.column_name is null; + return l_diffs; end; @@ -69,7 +71,8 @@ create or replace type body ut_cursor_details as l_csid pls_integer; l_csfrm pls_integer; l_attr_elt_type anytype; - l_anytype anytype; + l_anytype anytype; + l_is_collection boolean; begin self.cursor_info := ut_cursor_column_tab(); l_cursor_number := dbms_sql.to_cursor_number(a_cursor); @@ -79,6 +82,7 @@ create or replace type body ut_cursor_details as a_cursor := dbms_sql.to_refcursor(l_cursor_number); for cur in 1 .. l_columns_count loop + l_is_collection := ut_curr_usr_compound_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name); self.cursor_info.extend; self.cursor_info(cursor_info.last) := ut_cursor_column( l_columns_desc(cur).col_name, l_columns_desc(cur).col_schema_name, @@ -89,11 +93,10 @@ create or replace type body ut_cursor_details as null, 1, cur, - ut_curr_usr_compound_helper.get_column_type_desc(l_columns_desc(cur).col_type,true) + ut_curr_usr_compound_helper.get_column_type_desc(l_columns_desc(cur).col_type,true), + ut_utils.boolean_to_int(l_is_collection) ); - if l_columns_desc(cur).col_type = dbms_sql.user_defined_type - and - not ut_curr_usr_compound_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name) then + if l_columns_desc(cur).col_type = dbms_sql.user_defined_type and not l_is_collection then l_anytype := get_user_defined_type(l_columns_desc(cur).col_schema_name , l_columns_desc(cur).col_type_name ); for i in 1 .. get_anytype_attribute_count(l_anytype) loop l_attribute_typecode := l_anytype.getattreleminfo(pos => i, --First attribute @@ -105,9 +108,10 @@ create or replace type body ut_cursor_details as attr_elt_type => l_attr_elt_type, aname => l_aname); + l_is_collection := ut_curr_usr_compound_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name,l_attribute_typecode); self.cursor_info.extend; self.cursor_info(cursor_info.last) := ut_cursor_column( l_aname, - null, + l_columns_desc(cur).col_schema_name, null, l_prec, l_scale, @@ -115,7 +119,8 @@ create or replace type body ut_cursor_details as l_columns_desc(cur).col_name, 2, i, - ut_curr_usr_compound_helper.get_column_type_desc(l_attribute_typecode,false) + ut_curr_usr_compound_helper.get_column_type_desc(l_attribute_typecode,false), + ut_utils.boolean_to_int(l_is_collection) ); end loop; end if; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 2d12fe9f7..3114d61c6 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -248,6 +248,7 @@ create or replace type body ut_data_value_refcursor as l_result := case when (l_pk_missing_tab.count > 0) then 1 else 0 end; end if; + if l_result = 0 then if (self.cursor_details is not null and l_actual.cursor_details is not null) and (self.cursor_details != l_actual.cursor_details) then l_result := 1; diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index 696e89a14..8928452fd 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -51,6 +51,7 @@ create or replace type body ut_include as overriding member function run_matcher(self in out nocopy ut_include, a_actual ut_data_value) return boolean is l_result boolean; l_actual ut_data_value; + l_result1 integer; begin --TODO : Join by exclude an include should show differences if self.expected.data_type = a_actual.data_type then diff --git a/source/expectations/ut_expectation.tpb b/source/expectations/ut_expectation.tpb index 19775c707..0372e0ddf 100644 --- a/source/expectations/ut_expectation.tpb +++ b/source/expectations/ut_expectation.tpb @@ -33,12 +33,9 @@ create or replace type body ut_expectation as l_message varchar2(32767); begin --Negated matcher for include option. - if (l_matcher is of (ut_include)) then - l_expectation_result := l_matcher.run_matcher( self.actual_data ); - else - l_expectation_result := l_matcher.run_matcher_negated( self.actual_data ); - end if; + l_expectation_result := l_matcher.run_matcher_negated( self.actual_data ); l_expectation_result := coalesce(l_expectation_result,false); + l_message := coalesce( l_matcher.error_message( self.actual_data ), l_matcher.failure_message_when_negated( self.actual_data ) ); ut_expectation_processor.add_expectation_result( ut_expectation_result( ut_utils.to_test_result( l_expectation_result ), self.description, l_message ) ); end; diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 41fbaa3c4..eee70653a 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2442,7 +2442,7 @@ Diff:% begin --Arrange open l_actual for select username,rownum * 10 user_id from all_users where rownum < 5; - open l_expected for select username ,rownum user_id from all_users where rownum < 5; + open l_expected for select username||to_char(rownum) username ,rownum user_id from all_users where rownum < 5; --Act ut3.ut.expect(l_actual).not_to_contain(l_expected).join_by('USER_ID'); @@ -2456,7 +2456,7 @@ Diff:% begin --Arrange open l_actual for select username,rownum * 10 user_id from all_users where rownum < 5; - open l_expected for select username ,rownum user_id from all_users where rownum < 5; + open l_expected for select username||to_char(rownum) username ,rownum user_id from all_users where rownum < 5; --Act ut3.ut.expect(l_actual).not_to_include(l_expected).join_by('USER_ID'); From b094911993db65ed74cccc2f2258691ec3260e05 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Wed, 21 Nov 2018 07:29:31 +0000 Subject: [PATCH 57/83] Update tests --- .../data_values/ut_compound_data_helper.pkb | 2 +- .../data_values/ut_data_value_refcursor.tpb | 2 +- source/expectations/matchers/ut_include.tpb | 5 +++++ source/expectations/matchers/ut_include.tps | 1 + .../expectations/test_expectations_cursor.pkb | 22 +++++++++++++++---- .../expectations/test_expectations_cursor.pks | 2 +- 6 files changed, 27 insertions(+), 7 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 139e3fb8e..9fef0ad08 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -665,7 +665,7 @@ create or replace package body ut_compound_data_helper is end if; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - --dbms_output.put_line(l_compare_sql); + dbms_output.put_line(l_compare_sql); return l_compare_sql; end; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 3114d61c6..682911f5d 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -249,7 +249,7 @@ create or replace type body ut_data_value_refcursor as end if; - if l_result = 0 then + if l_result = 0 then if (self.cursor_details is not null and l_actual.cursor_details is not null) and (self.cursor_details != l_actual.cursor_details) then l_result := 1; end if; diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index 8928452fd..7859e24ff 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -64,6 +64,11 @@ create or replace type body ut_include as return l_result; end; + overriding member function run_matcher_negated(self in out nocopy ut_include, a_actual ut_data_value) return boolean is + begin + return run_matcher(a_actual); + end; + overriding member function failure_message(a_actual ut_data_value) return varchar2 is l_result varchar2(32767); l_actual ut_data_value; diff --git a/source/expectations/matchers/ut_include.tps b/source/expectations/matchers/ut_include.tps index 6ed32756c..b0e8a4bd3 100644 --- a/source/expectations/matchers/ut_include.tps +++ b/source/expectations/matchers/ut_include.tps @@ -30,6 +30,7 @@ create or replace type ut_include under ut_equal( member function negated return ut_include, member function get_negated return boolean, overriding member function run_matcher(self in out nocopy ut_include, a_actual ut_data_value) return boolean, + overriding member function run_matcher_negated(self in out nocopy ut_include, a_actual ut_data_value) return boolean, overriding member function failure_message(a_actual ut_data_value) return varchar2, overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2 ) diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index eee70653a..4e16d53e3 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2467,6 +2467,8 @@ Diff:% procedure not_inc_join_incl_cols_as_lst is l_actual sys_refcursor; l_expected sys_refcursor; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); begin --Arrange open l_actual for select rownum as rn, 'b' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; @@ -2474,7 +2476,19 @@ Diff:% --Act ut3.ut.expect(l_actual).not_to_include(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('RN'); --Assert - ut.expect(expectations.failed_expectations_data()).to_be_empty(); + l_expected_message := q'[%Actual: (refcursor [ count = 9 ]) +%Data-types: +%NUMBERCHARCHARCHARCHAR +%Data: +%% +%was expected not to include:(refcursor [ count = 3 ]) +%Data-types: +%NUMBERCHARCHARCHARCHAR +%Data: +%1adxc2adxc3adxc]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); end; procedure not_cont_join_incl_cols_as_lst is @@ -2483,7 +2497,7 @@ Diff:% begin --Arrange open l_actual for select rownum as rn, 'b' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; - open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + open l_expected for select rownum * 20 rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; --Act ut3.ut.expect(l_actual).not_to_contain(l_expected).include(ut3.ut_varchar2_list('RN','//A_Column','SOME_COL')).join_by('RN'); --Assert @@ -2496,7 +2510,7 @@ Diff:% begin --Arrange open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'y' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; - open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + open l_expected for select rownum * 20 as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; --Act ut3.ut.expect(l_actual).not_to_include(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('RN'); --Assert @@ -2509,7 +2523,7 @@ Diff:% begin --Arrange open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'y' SOME_COL, 'd' "Some_Col" from dual a connect by level < 10; - open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; + open l_expected for select rownum * 20 as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; --Act ut3.ut.expect(l_actual).not_to_contain(l_expected).exclude(ut3.ut_varchar2_list('//Some_Col','A_COLUMN')).join_by('RN'); --Assert diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index 0bd3e81d5..cbb029b9b 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -391,7 +391,7 @@ create or replace package test_expectations_cursor is --%test( Cursor not include data from another cursor with joinby clause) procedure cursor_not_to_include_joinby; - --%test(Cursor not include data with of columns to include and join by value) + --%test(Cursor not include data with of columns to include and join by value - Fail) procedure not_inc_join_incl_cols_as_lst; --%test(Cursor not contains data with of columns to include and join by value) From 21dca2b3dc5db4eca293af92ce762ed27a9cf180 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Wed, 21 Nov 2018 08:39:49 +0000 Subject: [PATCH 58/83] Resolve issue with nested table being join Removing XPATH --- .../data_values/ut_compound_data_helper.pkb | 29 +++- .../data_values/ut_compound_data_helper.pks | 2 + .../data_values/ut_data_value_refcursor.tpb | 142 +++++++++++++++--- .../data_values/ut_data_value_refcursor.tps | 2 + 4 files changed, 151 insertions(+), 24 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 9fef0ad08..2a6eefe34 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -429,7 +429,12 @@ create or replace package body ut_compound_data_helper is if a_data_info.access_path = l_pk_tab(l_index) then l_sql_stmt := case when a_join_by_stmt is null then null else ' and ' end; l_sql_stmt := l_sql_stmt ||' a.'||a_col_name||q'[ = ]'||' e.'||a_col_name; - end if; + elsif a_data_info.parent_name = l_pk_tab(l_index)then + --When then table is nested and join is on whole table + --TODO : Can this be done smarter ? + l_sql_stmt := case when a_join_by_stmt is null then null else ' and ' end; + l_sql_stmt := l_sql_stmt ||' a.'||a_col_name||q'[ = ]'||' e.'||a_col_name; + end if; exit when (a_data_info.access_path = l_pk_tab(l_index)) or l_index = l_pk_tab.count; l_index := l_pk_tab.next(l_index); end loop; @@ -457,7 +462,13 @@ create or replace package body ut_compound_data_helper is if a_data_info.access_path = l_pk_tab(l_index) then l_sql_stmt := case when a_partition_stmt is null then null else ',' end; l_sql_stmt := l_sql_stmt ||l_alias||a_col_name; + elsif a_data_info.parent_name = l_pk_tab(l_index)then + --When then table is nested and join is on whole table + --TODO : Can this be done smarter ? + l_sql_stmt := case when a_partition_stmt is null then null else ',' end; + l_sql_stmt := l_sql_stmt ||l_alias||a_col_name; end if; + exit when (a_data_info.access_path = l_pk_tab(l_index)) or l_index = l_pk_tab.count; l_index := l_pk_tab.next(l_index); end loop; @@ -515,7 +526,6 @@ create or replace package body ut_compound_data_helper is begin if l_cursor_info is not null then --Parition by piece - --TODO : Collection is intersting exmaple that we probably has to extract full xml and hash it. ut_utils.append_to_clob(a_partition_stmt,', row_number() over (partition by '); for i in 1..l_cursor_info.count loop if l_cursor_info(i).has_nested_col = 0 then @@ -665,7 +675,6 @@ create or replace package body ut_compound_data_helper is end if; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - dbms_output.put_line(l_compare_sql); return l_compare_sql; end; @@ -821,5 +830,19 @@ create or replace package body ut_compound_data_helper is return l_collection_elements; end; + function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list) return ut_cursor_column_tab is + l_result ut_cursor_column_tab; + begin + select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name, i.column_prec,i.column_scale,i.column_len, i.parent_name, + i.hierarchy_level,i.column_position, i.column_type, i.is_collection) + bulk collect into l_result + from table(a_cursor_details) i + left outer join table(a_incomparable_cols) c + on (i.access_path = c.column_value) + where c.column_value is null; + + return l_result; + end; + end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index f2b31f82e..84e8f787e 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -116,5 +116,7 @@ create or replace package ut_compound_data_helper authid definer is function contains_collection (a_cursor_info ut_cursor_column_tab) return number; + function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list) return ut_cursor_column_tab; + end; / diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 682911f5d..51c4c7f02 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -116,6 +116,69 @@ create or replace type body ut_data_value_refcursor as return l_result_string; end; + member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_join_by_xpath varchar2, a_unordered boolean,a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return clob is + c_max_rows integer := ut_utils.gc_diff_max_rows; + l_result clob; + l_results ut_utils.t_clob_tab := ut_utils.t_clob_tab(); + l_message varchar2(32767); + l_ut_owner varchar2(250) := ut_utils.ut_owner; + l_diff_row_count integer; + l_actual ut_compound_data_value; + l_diff_id ut_compound_data_helper.t_hash; + l_row_diffs ut_compound_data_helper.tt_row_diffs; + l_compare_type varchar2(10); + l_self ut_compound_data_value; + + function get_diff_message (a_row_diff ut_compound_data_helper.t_row_diffs,a_is_unordered boolean) return varchar2 is + begin + + if a_is_unordered then + if a_row_diff.pk_value is not null then + return ' PK '||a_row_diff.pk_value||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; + else + return rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; + end if; + else + return ' Row No. '||a_row_diff.rn||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; + end if; + end; + + begin + if not a_other is of (ut_compound_data_value) then + raise value_error; + end if; + + l_actual := treat(a_other as ut_compound_data_value); + + dbms_lob.createtemporary(l_result,true); + + l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); + + -- First tell how many rows are different + l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; + --TODO : Change message when the types not matching + if l_diff_row_count > 0 then + l_row_diffs := ut_compound_data_helper.get_rows_diff( + self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, + a_include_xpath, a_join_by_xpath, a_other is of (ut_data_value_refcursor), a_unordered); + l_message := chr(10) + ||'Rows: [ ' || l_diff_row_count ||' differences' + || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end + ||' ]'||chr(10)|| case when l_row_diffs.count = 0 then ' All rows are different as the columns are not matching.' else null end; + ut_utils.append_to_clob( l_result, l_message ); + for i in 1 .. l_row_diffs.count loop + l_results.extend; + l_results(l_results.last) := get_diff_message(l_row_diffs(i),a_unordered); + end loop; + ut_utils.append_to_clob(l_result,l_results); + else + l_message:= chr(10)||'Rows: [ all different ]'||chr(10)||' All rows are different as the columns are not matching.'; + ut_utils.append_to_clob( l_result, l_message ); + end if; + return l_result; + end; + member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return varchar2 is l_result clob; @@ -123,11 +186,19 @@ create or replace type body ut_data_value_refcursor as l_result_string varchar2(32767); l_actual ut_data_value_refcursor; l_column_diffs ut_compound_data_helper.tt_column_diffs := ut_compound_data_helper.tt_column_diffs(); - l_exclude_xpath varchar2(32767) := a_exclude_xpath; + l_act_cols ut_cursor_column_tab; + l_exp_cols ut_cursor_column_tab; + l_missing_pk ut_compound_data_helper.tt_missing_pk := ut_compound_data_helper.tt_missing_pk(); l_col_diffs ut_compound_data_helper.tt_column_diffs := ut_compound_data_helper.tt_column_diffs(); + c_max_rows integer := ut_utils.gc_diff_max_rows; + l_diff_id ut_compound_data_helper.t_hash; + l_diff_row_count integer; + l_row_diffs ut_compound_data_helper.tt_row_diffs; + l_message varchar2(32767); + function get_col_diff_text(a_col ut_compound_data_helper.t_column_diffs) return varchar2 is begin return @@ -155,35 +226,44 @@ create or replace type body ut_data_value_refcursor as return l_message; end; - function add_incomparable_cols_to_xpath( - a_column_diffs ut_compound_data_helper.tt_column_diffs, a_exclude_xpath varchar2 - ) return varchar2 is + function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_column_diffs ut_compound_data_helper.tt_column_diffs) return ut_cursor_column_tab is l_incomparable_cols ut_varchar2_list := ut_varchar2_list(); - l_result varchar2(32767); + l_filter_out ut_cursor_column_tab; begin for i in 1 .. a_column_diffs.count loop if a_column_diffs(i).diff_type in ('-','+') then l_incomparable_cols.extend; - l_incomparable_cols(l_incomparable_cols.last) := ut_utils.xmlgen_escaped_string(coalesce(a_column_diffs(i).expected_name,a_column_diffs(i).actual_name)); - end if; + l_incomparable_cols(l_incomparable_cols.last) := coalesce(a_column_diffs(i).expected_name,a_column_diffs(i).actual_name); + end if; end loop; - l_result := ut_utils.to_xpath(l_incomparable_cols); - if a_exclude_xpath is not null and l_result is not null then - l_result := l_result ||'|'||a_exclude_xpath; - else - l_result := coalesce(a_exclude_xpath, l_result); - end if; - return l_result; + + return ut_compound_data_helper.remove_incomparable_cols(a_cursor_details,l_incomparable_cols); end; + function get_diff_message (a_row_diff ut_compound_data_helper.t_row_diffs,a_is_unordered boolean) return varchar2 is + begin + + if a_is_unordered then + if a_row_diff.pk_value is not null then + return ' PK '||a_row_diff.pk_value||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; + else + return rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; + end if; + else + return ' Row No. '||a_row_diff.rn||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; + end if; + end; + begin if not a_other is of (ut_data_value_refcursor) then raise value_error; end if; l_actual := treat(a_other as ut_data_value_refcursor); - dbms_lob.createtemporary(l_result,true); + l_act_cols := l_actual.cursor_details.cursor_info; + l_exp_cols := self.cursor_details.cursor_info; + dbms_lob.createtemporary(l_result,true); --diff columns if not self.is_null and not l_actual.is_null then l_column_diffs := ut_compound_data_helper.get_columns_diff(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info); @@ -191,23 +271,45 @@ create or replace type body ut_data_value_refcursor as if l_column_diffs.count > 0 then ut_utils.append_to_clob(l_result,chr(10) || 'Columns:' || chr(10)); end if; - for i in 1 .. l_column_diffs.count loop l_results.extend; l_results(l_results.last) := get_col_diff_text(l_column_diffs(i)); end loop; ut_utils.append_to_clob(l_result, l_results); - l_exclude_xpath := add_incomparable_cols_to_xpath(l_column_diffs, a_exclude_xpath); + l_act_cols := remove_incomparable_cols(l_actual.cursor_details.cursor_info,l_column_diffs); + l_exp_cols := remove_incomparable_cols(self.cursor_details.cursor_info,l_column_diffs); end if; --check for missing pk if a_join_by_list.count > 0 then - l_missing_pk := ut_compound_data_helper.get_missing_pk(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info,a_join_by_list); + l_missing_pk := ut_compound_data_helper.get_missing_pk(l_exp_cols,l_act_cols,a_join_by_list); end if; --diff rows and row elements if the pk is not missing if l_missing_pk.count = 0 then - ut_utils.append_to_clob(l_result, self.get_data_diff(a_other, a_exclude_xpath, a_include_xpath, a_join_by_xpath, a_unordered)); + l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); + + -- First tell how many rows are different + l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; + l_results := ut_utils.t_clob_tab(); + if l_diff_row_count > 0 then + l_row_diffs := ut_compound_data_helper.get_rows_diff( + self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, + a_include_xpath, a_join_by_xpath, a_other is of (ut_data_value_refcursor), a_unordered); + l_message := chr(10) + ||'Rows: [ ' || l_diff_row_count ||' differences' + || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end + ||' ]'||chr(10)|| case when l_row_diffs.count = 0 then ' All rows are different as the columns are not matching.' else null end; + ut_utils.append_to_clob( l_result, l_message ); + for i in 1 .. l_row_diffs.count loop + l_results.extend; + l_results(l_results.last) := get_diff_message(l_row_diffs(i),a_unordered); + end loop; + ut_utils.append_to_clob(l_result,l_results); + else + l_message:= chr(10)||'Rows: [ all different ]'||chr(10)||' All rows are different as the columns are not matching.'; + ut_utils.append_to_clob( l_result, l_message ); + end if; else ut_utils.append_to_clob(l_result,chr(10) || 'Unable to join sets:' || chr(10)); for i in 1 .. l_missing_pk.count loop @@ -242,13 +344,11 @@ create or replace type body ut_data_value_refcursor as l_actual := treat(a_other as ut_data_value_refcursor); - --if we join by key and key is missing fail and report error if a_join_by_list.count > 0 then l_pk_missing_tab := ut_compound_data_helper.get_missing_pk(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info,a_join_by_list); l_result := case when (l_pk_missing_tab.count > 0) then 1 else 0 end; end if; - if l_result = 0 then if (self.cursor_details is not null and l_actual.cursor_details is not null) and (self.cursor_details != l_actual.cursor_details) then l_result := 1; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index ca740f191..ec1771846 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -52,6 +52,8 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) return self as result, member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), overriding member function to_string return varchar2, + member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_join_by_xpath varchar2, a_unordered boolean,a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return clob, member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ,a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return varchar2, overriding member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean := false, From 9dc266e256df344e717cc01ae433f401b3767f98 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Wed, 21 Nov 2018 21:46:28 +0000 Subject: [PATCH 59/83] Update test to be more generic --- test/core/expectations/test_expectations_cursor.pkb | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index b71f89d1f..06b8cbf17 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2393,7 +2393,7 @@ Diff:% --Act ut3.ut.expect(l_actual).not_to_contain(l_expected); --Assert - l_expected_message := q'[%Actual: (refcursor [ count = 18 ])% + l_expected_message := q'[%Actual: (refcursor [ count = % ])% %Data-types:% %VARCHAR2NUMBER% %Data:% @@ -2423,7 +2423,7 @@ Diff:% --Act ut3.ut.expect(l_actual).not_to_include(l_expected); --Assert - l_expected_message := q'[%Actual: (refcursor [ count = 18 ])% + l_expected_message := q'[%Actual: (refcursor [ count = % ])% %Data-types:% %VARCHAR2NUMBER% %Data:% From d96d602d83be1af655b1f057517605644ba803b9 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Wed, 21 Nov 2018 22:46:26 +0000 Subject: [PATCH 60/83] remove schema quantifier --- .../expectations/data_values/ut_compound_data_helper.pkb | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 2a6eefe34..4c2b29949 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -150,7 +150,7 @@ create or replace package body ut_compound_data_helper is l_sql := q'[with exp as ( select exp_item_data, exp_data_id, item_no rn,rownum col_no, - nvl2(exp_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,exp_item_data),null) pk_value, + nvl2(exp_item_data,ut_compound_data_helper.get_pk_value(i.join_by,exp_item_data),null) pk_value, s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val from ( select exp_data_id, ]'||l_exp_col_filter||q'[, :join_by join_by, item_no @@ -161,7 +161,7 @@ create or replace package body ut_compound_data_helper is ), act as ( select act_item_data, act_data_id, item_no rn, rownum col_no, - nvl2(act_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,act_item_data),null) pk_value, + nvl2(act_item_data,ut_compound_data_helper.get_pk_value(i.join_by,act_item_data),null) pk_value, s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val from ( select act_data_id, ]'||l_act_col_filter||q'[, :join_by join_by, item_no @@ -203,7 +203,7 @@ create or replace package body ut_compound_data_helper is select item_no as rn, case when exp_data_id is null then 'Extra:' else 'Missing:' end as diff_type, xmlserialize(content (extract((case when exp_data_id is null then act_item_data else exp_item_data end),'/*/*')) no indent) diffed_row, - nvl2(:join_by,ut3.ut_compound_data_helper.get_pk_value(:join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value + nvl2(:join_by,ut_compound_data_helper.get_pk_value(:join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value ,case when exp_data_id is null then 1 else 2 end rnk ,2 final_order from ut_compound_data_diff_tmp i @@ -681,7 +681,7 @@ create or replace package body ut_compound_data_helper is procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw) is begin forall idx in 1..a_diff_tab.count - insert into ut3.ut_compound_data_diff_tmp + insert into ut_compound_data_diff_tmp ( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no, duplicate_no ) values (a_diff_id, From 2b90c4b2f3aa9fb34715c75e526839df2799493c Mon Sep 17 00:00:00 2001 From: lwasylow Date: Wed, 21 Nov 2018 22:46:26 +0000 Subject: [PATCH 61/83] remove schema quantifier Changes to remove xpath from diff rows. Signed-off-by: lwasylow --- source/core/ut_utils.pkb | 5 + source/core/ut_utils.pks | 3 + .../data_values/ut_compound_data_helper.pkb | 578 +++++++++--------- .../data_values/ut_compound_data_helper.pks | 13 +- .../data_values/ut_compound_data_value.tpb | 3 +- .../data_values/ut_cursor_column.tpb | 28 +- .../data_values/ut_cursor_column.tps | 30 +- .../data_values/ut_data_value_refcursor.tpb | 86 +-- .../data_values/ut_data_value_refcursor.tps | 12 +- source/expectations/matchers/ut_equal.tpb | 6 +- source/expectations/matchers/ut_include.tpb | 2 +- .../expectations/test_expectations_cursor.pkb | 62 +- .../expectations/test_expectations_cursor.pks | 8 +- 13 files changed, 377 insertions(+), 459 deletions(-) diff --git a/source/core/ut_utils.pkb b/source/core/ut_utils.pkb index dbe57f866..5e13e608c 100644 --- a/source/core/ut_utils.pkb +++ b/source/core/ut_utils.pkb @@ -692,5 +692,10 @@ create or replace package body ut_utils is return l_result; end; + function serialize_data (a_data clob) return clob is + begin + return replace(a_data,chr(10)); + end; + end ut_utils; / diff --git a/source/core/ut_utils.pks b/source/core/ut_utils.pks index 83261584f..1b6dea73c 100644 --- a/source/core/ut_utils.pks +++ b/source/core/ut_utils.pks @@ -354,5 +354,8 @@ create or replace package ut_utils authid definer is */ function replace_multiline_comments(a_source clob) return clob; + --TODO optimize clob replace to be more efficient as might not work replace on large clobs + function serialize_data (a_data clob) return clob; + end ut_utils; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 2a6eefe34..6033322dc 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -132,266 +132,8 @@ create or replace package body ut_compound_data_helper is begin select replace((extract(a_item_data,a_join_by_xpath).getclobval()),chr(10)) into l_pk_value from dual; return l_pk_value; - end; - - function get_rows_diff_by_sql( - a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, - a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2, a_unordered boolean - ) return tt_row_diffs is - - l_act_col_filter varchar2(32767); - l_exp_col_filter varchar2(32767); - l_results tt_row_diffs; - l_sql varchar2(32767); - begin - l_act_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','act_item_data'); - l_exp_col_filter := get_columns_row_filter(a_exclude_xpath,a_include_xpath,'ucd','exp_item_data'); - - l_sql := q'[with exp as ( - select exp_item_data, exp_data_id, item_no rn,rownum col_no, - nvl2(exp_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,exp_item_data),null) pk_value, - s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val - from ( - select exp_data_id, ]'||l_exp_col_filter||q'[, :join_by join_by, item_no - from ut_compound_data_diff_tmp ucd - where diff_id = :diff_id - and ucd.exp_data_id = :self_guid) i, - table( xmlsequence( extract(i.exp_item_data,'/*/*') ) ) s - ), - act as ( - select act_item_data, act_data_id, item_no rn, rownum col_no, - nvl2(act_item_data,ut3.ut_compound_data_helper.get_pk_value(i.join_by,act_item_data),null) pk_value, - s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val - from ( - select act_data_id, ]'||l_act_col_filter||q'[, :join_by join_by, item_no - from ut_compound_data_diff_tmp ucd - where diff_id = :diff_id - and ucd.act_data_id = :other_guid ) i, - table( xmlsequence( extract(i.act_item_data,'/*/*') ) ) s - ) - select rn, diff_type, diffed_row, pk_value pk_value - from ( - select rn, diff_type, diffed_row, pk_value - ,case when diff_type = 'Actual:' then 1 else 2 end rnk - ,1 final_order - from ( ]'; - - if a_unordered then - l_sql := l_sql || q'[select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value - from - (select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item - from exp join act on exp.rn = act.rn and exp.col_name = act.col_name - where dbms_lob.compare(exp.col_val, act.col_val) != 0) - unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') - ))]'; - else - l_sql := l_sql || q'[ select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, null pk_value - from - (select nvl(exp.rn, act.rn) rn, - xmlagg(exp.col order by exp.col_no) exp_item, - xmlagg(act.col order by act.col_no) act_item - from exp exp join act act on exp.rn = act.rn and exp.col_name = act.col_name - where dbms_lob.compare(exp.col_val, act.col_val) != 0 - group by exp.rn, act.rn - ) - unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:')) - )]'; - end if; - - l_sql := l_sql || q'[union all - select - item_no as rn, case when exp_data_id is null then 'Extra:' else 'Missing:' end as diff_type, - xmlserialize(content (extract((case when exp_data_id is null then act_item_data else exp_item_data end),'/*/*')) no indent) diffed_row, - nvl2(:join_by,ut3.ut_compound_data_helper.get_pk_value(:join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value - ,case when exp_data_id is null then 1 else 2 end rnk - ,2 final_order - from ut_compound_data_diff_tmp i - where diff_id = :diff_id - and act_data_id is null or exp_data_id is null - ) - order by final_order, - case when final_order = 1 then rn else rnk end, - case when final_order = 1 then rnk else rn end ]'; - - execute immediate l_sql - bulk collect into l_results - using a_exclude_xpath, a_include_xpath, a_join_by_xpath, - a_diff_id, a_expected_dataset_guid, - a_exclude_xpath,a_include_xpath, a_join_by_xpath, - a_diff_id, a_actual_dataset_guid, - a_join_by_xpath,a_join_by_xpath, a_diff_id; - - return l_results; - end; - - function get_rows_diff( - a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, - a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2 - ) return tt_row_diffs is - l_column_filter varchar2(32767); - l_results tt_row_diffs; - begin - l_column_filter := get_columns_filter(a_exclude_xpath,a_include_xpath); - execute immediate q'[ - with - diff_info as ( select item_no - from - (select item_no from ut_compound_data_diff_tmp ucdc where diff_id = :diff_guid order by item_no asc) - where rownum <= :max_rows) - select * - from (select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, null pk_value - from (select nvl(exp.rn, act.rn) rn, - xmlagg(exp.col order by exp.col_no) exp_item, - xmlagg(act.col order by act.col_no) act_item - from (select r.item_no as rn, rownum col_no, s.column_value col, - s.column_value.getRootElement() col_name, - s.column_value.getclobval() col_val - from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_data item_data_no_filter - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :self_guid - and ucd.item_no = i.item_no - ) r, - table( xmlsequence( extract(r.item_data,'/*/*') ) ) s - ) exp - join ( - select item_no as rn, rownum col_no, s.column_value col, - s.column_value.getRootElement() col_name, - s.column_value.getclobval() col_val - from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_data item_data_no_filter - from ut_compound_data_tmp ucd, - diff_info i - where ucd.data_id = :other_guid - and ucd.item_no = i.item_no - ) r, - table( xmlsequence( extract(r.item_data,'/*/*') ) ) s - ) act - on exp.rn = act.rn and exp.col_name = act.col_name - where dbms_lob.compare(exp.col_val, act.col_val) != 0 - group by exp.rn, act.rn - ) - unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') ) - ) - union all - select nvl(exp.item_no, act.item_no) rn, - case when exp.item_no is null then 'Extra:' else 'Missing:' end as diff_type, - xmlserialize(content nvl(exp.item_data, act.item_data) no indent) diffed_row, - null pk_value - from (select ucd.item_no, extract(ucd.item_data,'/*/*') item_data - from ut_compound_data_tmp ucd - where ucd.data_id = :self_guid - and ucd.item_no in (select i.item_no from diff_info i) - ) exp - full outer join ( - select ucd.item_no, extract(ucd.item_data,'/*/*') item_data - from ut_compound_data_tmp ucd - where ucd.data_id = :other_guid - and ucd.item_no in (select i.item_no from diff_info i) - )act - on exp.item_no = act.item_no - where exp.item_no is null or act.item_no is null - order by 1, 2]' - bulk collect into l_results - using a_diff_id, a_max_rows, - a_exclude_xpath, a_include_xpath, a_expected_dataset_guid, - a_exclude_xpath, a_include_xpath, a_actual_dataset_guid, - a_expected_dataset_guid, a_actual_dataset_guid; - return l_results; - end; - - function get_rows_diff( - a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, - a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_refcursor boolean, a_unordered boolean - ) return tt_row_diffs is - l_result tt_row_diffs := tt_row_diffs(); - begin - case - when a_refcursor then - l_result := get_rows_diff_by_sql(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, - a_max_rows, a_exclude_xpath, a_include_xpath ,a_join_by_xpath, a_unordered); - else - l_result := get_rows_diff(a_expected_dataset_guid, a_actual_dataset_guid, a_diff_id, - a_max_rows, a_exclude_xpath, a_include_xpath); - end case; - return l_result; - end; - - function get_hash(a_data raw, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash is - begin - return dbms_crypto.hash(a_data, a_hash_type); - end; - - function get_hash(a_data clob, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash is - begin - return dbms_crypto.hash(a_data, a_hash_type); - end; - - function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer :=30) return number is - begin - return dbms_utility.get_hash_value(a_string,a_base,a_size); - end; - - function columns_hash( - a_data_value_cursor ut_data_value_refcursor, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_hash_type binary_integer := dbms_crypto.hash_sh1 - ) return t_hash is - l_cols_hash t_hash; - begin - if not a_data_value_cursor.is_null then - execute immediate - q'[select dbms_crypto.hash(replace(x.item_data.getclobval(),'>CHAR<','>VARCHAR2<'),]'||a_hash_type||') ' || - ' from ( select '||get_columns_filter(a_exclude_xpath, a_include_xpath)|| - ' from (select :columns_info as item_data from dual ) ucd' || - ' ) x' - into l_cols_hash using a_exclude_xpath,a_include_xpath, a_data_value_cursor.columns_info; - end if; - return l_cols_hash; - end; - - function is_pk_exists(a_expected_cursor xmltype,a_actual_cursor xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2,a_join_by_xpath varchar2) - return tt_missing_pk is - l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); - l_column_filter varchar2(32767); - l_no_missing_keys tt_missing_pk := tt_missing_pk(); - - begin - if a_join_by_xpath is not null then - l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); - l_column_filter := get_columns_row_filter(a_exclude_xpath, a_include_xpath); - - execute immediate q'[ - with xpaths_tab as (select column_value xpath from table(:xpath_tabs)), - expected_column_info as ( select :expected as item_data from dual ), - actual_column_info as ( select :actual as item_data from dual ) - select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$'),diif_type from - ( - (select xpath,'e' diif_type from xpaths_tab - minus - select xpath,'e' diif_type - from ( select ]'||l_column_filter||q'[ from expected_column_info ucd) x - ,xpaths_tab - where xmlexists (xpaths_tab.xpath passing x.item_data) - ) - union all - (select xpath,'a' diif_type from xpaths_tab - minus - select xpath,'a' diif_type - from ( select ]'||l_column_filter||q'[ from actual_column_info ucd) x - ,xpaths_tab - where xmlexists (xpaths_tab.xpath passing x.item_data) - ) - )]' bulk collect into l_no_missing_keys - using l_pk_xpath_tabs,a_expected_cursor,a_actual_cursor, - a_exclude_xpath, a_include_xpath, - a_exclude_xpath, a_include_xpath; - - end if; - - return l_no_missing_keys; - end; - + end; + procedure generate_not_equal_stmt(a_data_info ut_cursor_column, a_pk_table ut_varchar2_list, a_not_equal_stmt in out nocopy clob, a_col_name varchar2) is l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); @@ -449,9 +191,10 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(a_equal_stmt,l_sql_stmt); end; - --TODO : Scenario where join by is on whole type not a column of type e.g. NESTEDTABLE - procedure generate_partition_stmt(a_data_info ut_cursor_column, a_partition_stmt in out nocopy clob,a_pk_table in ut_varchar2_list,a_col_name in varchar2) is - l_alias varchar2(10) := 'ucd.'; + procedure generate_partition_stmt(a_data_info ut_cursor_column, a_partition_stmt in out nocopy clob, + a_pk_table in ut_varchar2_list,a_col_name in varchar2,a_alias varchar2 := 'ucd.') is + + l_alias varchar2(10) := a_alias; l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); l_index integer; l_sql_stmt varchar2(32767); @@ -478,9 +221,9 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(a_partition_stmt,l_sql_stmt); end; - procedure generate_select_stmt(a_data_info ut_cursor_column,a_sql_stmt in out nocopy clob, a_col_name varchar2) is + procedure generate_select_stmt(a_data_info ut_cursor_column,a_sql_stmt in out nocopy clob, a_col_name varchar2,a_alias varchar2 := 'ucd.') is l_sql_stmt clob; - l_alias varchar2(10) := 'ucd.'; + l_alias varchar2(10) := a_alias; l_col_syntax varchar2(4000); l_ut_owner varchar2(250) := ut_utils.ut_owner; begin @@ -491,7 +234,7 @@ create or replace package body ut_compound_data_helper is end if; ut_utils.append_to_clob(a_sql_stmt,','||l_col_syntax); end; - + procedure generate_xmltab_stmt(a_data_info ut_cursor_column,a_sql_stmt in out nocopy clob, a_col_name varchar2) is l_sql_stmt varchar2(32767); l_col_type varchar2(4000); @@ -513,7 +256,7 @@ create or replace package body ut_compound_data_helper is '('||a_data_info.column_len||')' else null end; end if; - l_sql_stmt := ' '||a_col_name||' '||l_col_type||q'[ PATH ']'||a_data_info.access_path||q'[',]'; + l_sql_stmt := case when a_sql_stmt is null then '' else ', ' end ||a_col_name||' '||l_col_type||q'[ PATH ']'||a_data_info.access_path||q'[']'; ut_utils.append_to_clob(a_sql_stmt, l_sql_stmt); end; @@ -529,11 +272,7 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(a_partition_stmt,', row_number() over (partition by '); for i in 1..l_cursor_info.count loop if l_cursor_info(i).has_nested_col = 0 then - l_col_name := case when l_cursor_info(i).parent_name is null then - l_cursor_info(i).xml_valid_name - else - l_cursor_info(i).nested_name - end; + l_col_name := l_cursor_info(i).transformed_name; --Get XMLTABLE column list generate_xmltab_stmt(l_cursor_info(i),a_xml_stmt,l_col_name); --Get Select statment list of columns @@ -583,13 +322,10 @@ create or replace package body ut_compound_data_helper is begin dbms_lob.createtemporary(l_compare_sql, true); - - --TODO: Resolve issues with collection and nested tables, can we extract by internal column name if defined e.g. xml of colval.id.getclobval() - gen_sql_pieces_out_of_cursor(a_other, a_join_by_list, l_xmltable_stmt, l_select_stmt, l_partition_stmt, l_equal_stmt, l_join_on_stmt, l_not_equal_stmt); - + l_temp_string := 'with exp as ( select ucd.* '; ut_utils.append_to_clob(l_compare_sql, l_temp_string); ut_utils.append_to_clob(l_compare_sql,l_partition_stmt); @@ -604,13 +340,14 @@ create or replace package body ut_compound_data_helper is ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]'; ut_utils.append_to_clob(l_compare_sql, l_temp_string); + ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt); + ut_utils.append_to_clob(l_compare_sql,case when l_xmltable_stmt is null then '' else ',' end||q'[ item_data xmltype PATH '*']'); + if not a_unordered then - ut_utils.append_to_clob(l_compare_sql,'POSITION for ordinality, '); + ut_utils.append_to_clob(l_compare_sql,', POSITION for ordinality '); end if; - ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt); - - l_temp_string := q'[ item_data xmltype PATH '*' ) ucd where data_id = :self_guid ) ucd ) ,]'; + l_temp_string := q'[) ucd where data_id = :self_guid ) ucd ) ,]'; ut_utils.append_to_clob(l_compare_sql,l_temp_string); l_temp_string :='act as ( select ucd.* '; @@ -627,11 +364,14 @@ create or replace package body ut_compound_data_helper is ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' ; ut_utils.append_to_clob(l_compare_sql,l_temp_string); + ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt); + ut_utils.append_to_clob(l_compare_sql,case when l_xmltable_stmt is null then '' else ',' end||q'[ item_data xmltype PATH '*']'); + if not a_unordered then - ut_utils.append_to_clob(l_compare_sql,'POSITION for ordinality, '); + ut_utils.append_to_clob(l_compare_sql,', POSITION for ordinality '); end if; - ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt||q'[ item_data xmltype PATH '*') ucd where data_id = :other_guid ) ucd ) ]'); + ut_utils.append_to_clob(l_compare_sql,q'[ ) ucd where data_id = :other_guid ) ucd ) ]'); l_temp_string := ' select a.item_data as act_item_data, a.data_id act_data_id,' ||'e.item_data as exp_item_data, e.data_id exp_data_id, '|| @@ -677,11 +417,260 @@ create or replace package body ut_compound_data_helper is return l_compare_sql; end; - + + function get_column_extract_path(a_cursor_info ut_cursor_column_tab) return ut_varchar2_list is + l_column_list ut_varchar2_list := ut_varchar2_list(); + begin + for i in 1..a_cursor_info.count loop + l_column_list.extend; + l_column_list(l_column_list.last) := a_cursor_info(i).access_path; + end loop; + return l_column_list; + end; + + + function get_rows_diff_by_sql(a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, + a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, + a_join_by_list ut_varchar2_list, a_unordered boolean + ) return tt_row_diffs is + + l_act_col_filter varchar2(32767); + l_exp_col_filter varchar2(32767); + l_act_extract_xpath varchar2(32767):= ut_utils.to_xpath(get_column_extract_path(a_act_cursor_info)); + l_exp_extract_xpath varchar2(32767):= ut_utils.to_xpath(get_column_extract_path(a_exp_cursor_info)); + l_join_xpath varchar2(32767) := ut_utils.to_xpath(a_join_by_list); + l_results tt_row_diffs; + l_sql varchar2(32767); + begin + + l_sql := q'[with exp as ( + select exp_item_data, exp_data_id, item_no rn,rownum col_no, pk_value, + s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val + from ( + select exp_data_id, extract( ucd.exp_item_data, :column_path ) exp_item_data, item_no, + ut_compound_data_helper.get_pk_value(:join_by, ucd.exp_item_data) pk_value + from ut_compound_data_diff_tmp ucd + where diff_id = :diff_id + and ucd.exp_data_id = :self_guid) i, + table( xmlsequence( extract(i.exp_item_data,'/*') ) ) s + ), + act as ( + select act_item_data, act_data_id, item_no rn, rownum col_no, pk_value, + s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val + from ( + select act_data_id, extract( ucd.act_item_data, :column_path ) act_item_data, item_no, + ut_compound_data_helper.get_pk_value(:join_by, ucd.act_item_data) pk_value + from ut_compound_data_diff_tmp ucd + where diff_id = :diff_id + and ucd.act_data_id = :other_guid ) i, + table( xmlsequence( extract(i.act_item_data,'/*') ) ) s + ) + select rn, diff_type, diffed_row, pk_value pk_value + from ( + select rn, diff_type, diffed_row, pk_value + ,case when diff_type = 'Actual:' then 1 else 2 end rnk + ,1 final_order + from ( ]'; + + if a_unordered then + l_sql := l_sql || q'[select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value + from + (select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item + from exp join act on exp.rn = act.rn and exp.col_name = act.col_name + where dbms_lob.compare(exp.col_val, act.col_val) != 0) + unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') + ))]'; + else + l_sql := l_sql || q'[ select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, null pk_value + from + (select nvl(exp.rn, act.rn) rn, + xmlagg(exp.col order by exp.col_no) exp_item, + xmlagg(act.col order by act.col_no) act_item + from exp exp join act act on exp.rn = act.rn and exp.col_name = act.col_name + where dbms_lob.compare(exp.col_val, act.col_val) != 0 + group by exp.rn, act.rn + ) + unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:')) + )]'; + end if; + + l_sql := l_sql || q'[union all + select + item_no as rn, case when exp_data_id is null then 'Extra:' else 'Missing:' end as diff_type, + xmlserialize(content (extract((case when exp_data_id is null then act_item_data else exp_item_data end),'/*/*')) no indent) diffed_row, + nvl2(:join_by,ut_compound_data_helper.get_pk_value(:join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value + ,case when exp_data_id is null then 1 else 2 end rnk + ,2 final_order + from ut_compound_data_diff_tmp i + where diff_id = :diff_id + and act_data_id is null or exp_data_id is null + ) + order by final_order, + case when final_order = 1 then rn else rnk end, + case when final_order = 1 then rnk else rn end ]'; + + execute immediate l_sql + bulk collect into l_results + using l_exp_extract_xpath,l_join_xpath,a_diff_id, a_expected_dataset_guid, + l_act_extract_xpath,l_join_xpath,a_diff_id, a_actual_dataset_guid, + l_join_xpath,l_join_xpath,a_diff_id; + + return l_results; + end; + + function get_rows_diff( + a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, + a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2 + ) return tt_row_diffs is + l_column_filter varchar2(32767); + l_results tt_row_diffs; + begin + l_column_filter := get_columns_filter(a_exclude_xpath,a_include_xpath); + execute immediate q'[ + with + diff_info as ( select item_no + from + (select item_no from ut_compound_data_diff_tmp ucdc where diff_id = :diff_guid order by item_no asc) + where rownum <= :max_rows) + select * + from (select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, null pk_value + from (select nvl(exp.rn, act.rn) rn, + xmlagg(exp.col order by exp.col_no) exp_item, + xmlagg(act.col order by act.col_no) act_item + from (select r.item_no as rn, rownum col_no, s.column_value col, + s.column_value.getRootElement() col_name, + s.column_value.getclobval() col_val + from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_data item_data_no_filter + from ut_compound_data_tmp ucd, + diff_info i + where ucd.data_id = :self_guid + and ucd.item_no = i.item_no + ) r, + table( xmlsequence( extract(r.item_data,'/*/*') ) ) s + ) exp + join ( + select item_no as rn, rownum col_no, s.column_value col, + s.column_value.getRootElement() col_name, + s.column_value.getclobval() col_val + from (select ]'||l_column_filter||q'[, ucd.item_no, ucd.item_data item_data_no_filter + from ut_compound_data_tmp ucd, + diff_info i + where ucd.data_id = :other_guid + and ucd.item_no = i.item_no + ) r, + table( xmlsequence( extract(r.item_data,'/*/*') ) ) s + ) act + on exp.rn = act.rn and exp.col_name = act.col_name + where dbms_lob.compare(exp.col_val, act.col_val) != 0 + group by exp.rn, act.rn + ) + unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') ) + ) + union all + select nvl(exp.item_no, act.item_no) rn, + case when exp.item_no is null then 'Extra:' else 'Missing:' end as diff_type, + xmlserialize(content nvl(exp.item_data, act.item_data) no indent) diffed_row, + null pk_value + from (select ucd.item_no, extract(ucd.item_data,'/*/*') item_data + from ut_compound_data_tmp ucd + where ucd.data_id = :self_guid + and ucd.item_no in (select i.item_no from diff_info i) + ) exp + full outer join ( + select ucd.item_no, extract(ucd.item_data,'/*/*') item_data + from ut_compound_data_tmp ucd + where ucd.data_id = :other_guid + and ucd.item_no in (select i.item_no from diff_info i) + )act + on exp.item_no = act.item_no + where exp.item_no is null or act.item_no is null + order by 1, 2]' + bulk collect into l_results + using a_diff_id, a_max_rows, + a_exclude_xpath, a_include_xpath, a_expected_dataset_guid, + a_exclude_xpath, a_include_xpath, a_actual_dataset_guid, + a_expected_dataset_guid, a_actual_dataset_guid; + return l_results; + end; + + function get_hash(a_data raw, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash is + begin + return dbms_crypto.hash(a_data, a_hash_type); + end; + + function get_hash(a_data clob, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash is + begin + return dbms_crypto.hash(a_data, a_hash_type); + end; + + function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer :=30) return number is + begin + return dbms_utility.get_hash_value(a_string,a_base,a_size); + end; + + function columns_hash( + a_data_value_cursor ut_data_value_refcursor, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_hash_type binary_integer := dbms_crypto.hash_sh1 + ) return t_hash is + l_cols_hash t_hash; + begin + if not a_data_value_cursor.is_null then + execute immediate + q'[select dbms_crypto.hash(replace(x.item_data.getclobval(),'>CHAR<','>VARCHAR2<'),]'||a_hash_type||') ' || + ' from ( select '||get_columns_filter(a_exclude_xpath, a_include_xpath)|| + ' from (select :columns_info as item_data from dual ) ucd' || + ' ) x' + into l_cols_hash using a_exclude_xpath,a_include_xpath, a_data_value_cursor.columns_info; + end if; + return l_cols_hash; + end; + + function is_pk_exists(a_expected_cursor xmltype,a_actual_cursor xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2,a_join_by_xpath varchar2) + return tt_missing_pk is + l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); + l_column_filter varchar2(32767); + l_no_missing_keys tt_missing_pk := tt_missing_pk(); + + begin + if a_join_by_xpath is not null then + l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); + l_column_filter := get_columns_row_filter(a_exclude_xpath, a_include_xpath); + + execute immediate q'[ + with xpaths_tab as (select column_value xpath from table(:xpath_tabs)), + expected_column_info as ( select :expected as item_data from dual ), + actual_column_info as ( select :actual as item_data from dual ) + select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$'),diif_type from + ( + (select xpath,'e' diif_type from xpaths_tab + minus + select xpath,'e' diif_type + from ( select ]'||l_column_filter||q'[ from expected_column_info ucd) x + ,xpaths_tab + where xmlexists (xpaths_tab.xpath passing x.item_data) + ) + union all + (select xpath,'a' diif_type from xpaths_tab + minus + select xpath,'a' diif_type + from ( select ]'||l_column_filter||q'[ from actual_column_info ucd) x + ,xpaths_tab + where xmlexists (xpaths_tab.xpath passing x.item_data) + ) + )]' bulk collect into l_no_missing_keys + using l_pk_xpath_tabs,a_expected_cursor,a_actual_cursor, + a_exclude_xpath, a_include_xpath, + a_exclude_xpath, a_include_xpath; + + end if; + + return l_no_missing_keys; + end; + procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw) is begin forall idx in 1..a_diff_tab.count - insert into ut3.ut_compound_data_diff_tmp + insert into ut_compound_data_diff_tmp ( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no, duplicate_no ) values (a_diff_id, @@ -779,6 +768,18 @@ create or replace package body ut_compound_data_helper is order by type desc,name; return l_missing_pk; end; + + function validate_attributes(a_cursor_info ut_cursor_column_tab,a_filter_list ut_varchar2_list) + return ut_varchar2_list is + l_result ut_varchar2_list := ut_varchar2_list(); + begin + select col_name bulk collect into l_result + from (select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_name + from table(a_filter_list)) flr left outer join table(a_cursor_info) cur + on (flr.col_name = cur.access_path) where cur.access_path is null; + + return l_result; + end; function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_cursor_column_tab is @@ -844,5 +845,14 @@ create or replace package body ut_compound_data_helper is return l_result; end; + function generate_missing_cols_warn_msg(a_missing_columns ut_varchar2_list,a_attribute in varchar2) return varchar2 is + l_warn_msg varchar2(32767) := 'For specified option :'||a_attribute||' following columns not exists in cursor:'||chr(10); + begin + for i in 1..a_missing_columns.count loop + l_warn_msg := l_warn_msg||a_missing_columns(i)||chr(10); + end loop; + return l_warn_msg; + end; + end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 84e8f787e..50d70974d 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -58,6 +58,7 @@ create or replace package ut_compound_data_helper authid definer is type t_diff_tab is table of t_diff_rec; + function get_column_info_xml(a_column_details ut_key_anyval_pair) return xmltype; function get_columns_filter( @@ -72,10 +73,14 @@ create or replace package ut_compound_data_helper authid definer is function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, - a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2,a_refcursor boolean, a_unordered boolean + a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2 ) return tt_row_diffs; + function get_rows_diff_by_sql(a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, + a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, + a_join_by_list ut_varchar2_list, a_unordered boolean + ) return tt_row_diffs; + subtype t_hash is raw(128); function get_hash(a_data raw, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash; @@ -111,6 +116,8 @@ create or replace package ut_compound_data_helper authid definer is function get_missing_pk(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab, a_current_list ut_varchar2_list) return tt_missing_pk; + function validate_attributes(a_cursor_info ut_cursor_column_tab, a_filter_list ut_varchar2_list) return ut_varchar2_list; + function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_cursor_column_tab; @@ -118,5 +125,7 @@ create or replace package ut_compound_data_helper authid definer is function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list) return ut_cursor_column_tab; + function generate_missing_cols_warn_msg(a_missing_columns ut_varchar2_list,a_attribute in varchar2) return varchar2; + end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 8db8071df..a1cb14993 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -118,14 +118,13 @@ create or replace type body ut_compound_data_value as dbms_lob.createtemporary(l_result,true); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); - -- First tell how many rows are different l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; --TODO : Change message when the types not matching if l_diff_row_count > 0 then l_row_diffs := ut_compound_data_helper.get_rows_diff( self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, - a_include_xpath, a_join_by_xpath, a_other is of (ut_data_value_refcursor), a_unordered); + a_include_xpath); l_message := chr(10) ||'Rows: [ ' || l_diff_row_count ||' differences' || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index 1c650708e..aba9236cc 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -6,24 +6,24 @@ create or replace type body ut_cursor_column as a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, a_col_position integer, a_col_type varchar2, a_collection integer) is begin - self.parent_name := a_parent_name; - self.hierarchy_level := a_hierarchy_level; - self.column_position := a_col_position; - self.column_prec := a_col_prec; - self.column_len := a_col_max_len; - self.column_scale := a_col_scale; - self.column_name := TRIM( BOTH '''' FROM a_col_name); + self.parent_name := a_parent_name; + self.hierarchy_level := a_hierarchy_level; + self.column_position := a_col_position; + self.column_prec := a_col_prec; + self.column_len := a_col_max_len; + self.column_scale := a_col_scale; + self.column_name := TRIM( BOTH '''' FROM a_col_name); self.column_type_name := a_col_type_name; - self.access_path := case when self.parent_name is null then self.column_name else self.parent_name||'/'||self.column_name end; - self.nested_name := case when self.parent_name is null then - null + self.access_path := case when self.parent_name is null then self.column_name else self.parent_name||'/'||self.column_name end; + self.xml_valid_name := '"'||self.column_name||'"'; + self.transformed_name := case when self.parent_name is null then + self.xml_valid_name else '"'||ut_compound_data_helper.get_fixed_size_hash(self.parent_name||self.column_name)||'"' end; - self.xml_valid_name := '"'||self.column_name||'"'; - self.column_type := a_col_type; - self.column_schema := a_col_schema_name; - self.is_sql_diffable := case when lower(self.column_type) = 'user_defined_type' then + self.column_type := a_col_type; + self.column_schema := a_col_schema_name; + self.is_sql_diffable := case when lower(self.column_type) = 'user_defined_type' then 0 else ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)) diff --git a/source/expectations/data_values/ut_cursor_column.tps b/source/expectations/data_values/ut_cursor_column.tps index 82ec96f02..7782a0d8e 100644 --- a/source/expectations/data_values/ut_cursor_column.tps +++ b/source/expectations/data_values/ut_cursor_column.tps @@ -1,21 +1,21 @@ create or replace type ut_cursor_column force authid current_user as object ( - parent_name varchar2(100), - access_path varchar2(500), - has_nested_col number(1,0), - nested_name varchar2(32), - hierarchy_level number, - column_position number, - xml_valid_name varchar2(100), - column_name varchar2(100), - column_type varchar2(100), + parent_name varchar2(100), + access_path varchar2(500), + has_nested_col number(1,0), + transformed_name varchar2(32), + hierarchy_level number, + column_position number, + xml_valid_name varchar2(100), + column_name varchar2(100), + column_type varchar2(100), column_type_name varchar2(100), - column_schema varchar2(100), - column_prec integer, - column_len integer, - column_scale integer, - is_sql_diffable number(1, 0), - is_collection number(1, 0), + column_schema varchar2(100), + column_prec integer, + column_len integer, + column_scale integer, + is_sql_diffable number(1, 0), + is_collection number(1, 0), member procedure init(self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 51c4c7f02..06fe0fdc9 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -116,71 +116,7 @@ create or replace type body ut_data_value_refcursor as return l_result_string; end; - member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2, a_unordered boolean,a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return clob is - c_max_rows integer := ut_utils.gc_diff_max_rows; - l_result clob; - l_results ut_utils.t_clob_tab := ut_utils.t_clob_tab(); - l_message varchar2(32767); - l_ut_owner varchar2(250) := ut_utils.ut_owner; - l_diff_row_count integer; - l_actual ut_compound_data_value; - l_diff_id ut_compound_data_helper.t_hash; - l_row_diffs ut_compound_data_helper.tt_row_diffs; - l_compare_type varchar2(10); - l_self ut_compound_data_value; - - function get_diff_message (a_row_diff ut_compound_data_helper.t_row_diffs,a_is_unordered boolean) return varchar2 is - begin - - if a_is_unordered then - if a_row_diff.pk_value is not null then - return ' PK '||a_row_diff.pk_value||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - else - return rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - end if; - else - return ' Row No. '||a_row_diff.rn||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - end if; - end; - - begin - if not a_other is of (ut_compound_data_value) then - raise value_error; - end if; - - l_actual := treat(a_other as ut_compound_data_value); - - dbms_lob.createtemporary(l_result,true); - - l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); - - -- First tell how many rows are different - l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; - --TODO : Change message when the types not matching - if l_diff_row_count > 0 then - l_row_diffs := ut_compound_data_helper.get_rows_diff( - self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, - a_include_xpath, a_join_by_xpath, a_other is of (ut_data_value_refcursor), a_unordered); - l_message := chr(10) - ||'Rows: [ ' || l_diff_row_count ||' differences' - || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end - ||' ]'||chr(10)|| case when l_row_diffs.count = 0 then ' All rows are different as the columns are not matching.' else null end; - ut_utils.append_to_clob( l_result, l_message ); - for i in 1 .. l_row_diffs.count loop - l_results.extend; - l_results(l_results.last) := get_diff_message(l_row_diffs(i),a_unordered); - end loop; - ut_utils.append_to_clob(l_result,l_results); - else - l_message:= chr(10)||'Rows: [ all different ]'||chr(10)||' All rows are different as the columns are not matching.'; - ut_utils.append_to_clob( l_result, l_message ); - end if; - return l_result; - end; - - member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, - a_unordered boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return varchar2 is + member function diff( a_other ut_data_value, a_unordered boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return varchar2 is l_result clob; l_results ut_utils.t_clob_tab := ut_utils.t_clob_tab(); l_result_string varchar2(32767); @@ -293,9 +229,9 @@ create or replace type body ut_data_value_refcursor as l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; l_results := ut_utils.t_clob_tab(); if l_diff_row_count > 0 then - l_row_diffs := ut_compound_data_helper.get_rows_diff( - self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, - a_include_xpath, a_join_by_xpath, a_other is of (ut_data_value_refcursor), a_unordered); + --TODO : since columns can differ we need to pass both list or get common denominator + l_row_diffs := ut_compound_data_helper.get_rows_diff_by_sql( + l_exp_cols,l_act_cols, self.data_id, l_actual.data_id, l_diff_id,a_join_by_list , a_unordered); l_message := chr(10) ||'Rows: [ ' || l_diff_row_count ||' differences' || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end @@ -329,21 +265,19 @@ create or replace type body ut_data_value_refcursor as return l_result_string; end; - overriding member function compare_implementation (a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean := false, - a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list()) - return integer is + overriding member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false, + a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return integer is l_result integer := 0; l_actual ut_data_value_refcursor; - l_pk_missing_tab ut_compound_data_helper.tt_missing_pk; begin if not a_other is of (ut_data_value_refcursor) then raise value_error; end if; - + l_actual := treat(a_other as ut_data_value_refcursor); - + if a_join_by_list.count > 0 then l_pk_missing_tab := ut_compound_data_helper.get_missing_pk(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info,a_join_by_list); l_result := case when (l_pk_missing_tab.count > 0) then 1 else 0 end; @@ -365,9 +299,9 @@ create or replace type body ut_data_value_refcursor as return self.elements_count = 0; end; - member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor is + member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor is l_result ut_data_value_refcursor := self; - begin + begin if l_result.cursor_details.cursor_info is not null then l_result.cursor_details.cursor_info := ut_compound_data_helper.inc_exc_columns_from_cursor(l_result.cursor_details.cursor_info,a_exclude_xpath,a_include_xpath); end if; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index ec1771846..2a6b58ba1 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -52,13 +52,9 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) return self as result, member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), overriding member function to_string return varchar2, - member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2, a_unordered boolean,a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return clob, - member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false - ,a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return varchar2, - overriding member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean := false, - a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return integer, + member function diff( a_other ut_data_value, a_unordered boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return varchar2, + overriding member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false, + a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return integer, overriding member function is_empty return boolean, - member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor -) + member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor) / diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index 489e9f41f..d790118af 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -255,7 +255,6 @@ create or replace type body ut_equal as member function get_join_by_list return ut_varchar2_list is begin - --TODO : zamiast zmieniac path zmodyfikuj get functions return ( coalesce(join_columns, ut_varchar2_list()) ); end; @@ -268,8 +267,7 @@ create or replace type body ut_equal as l_result := 0 = treat(self.expected as ut_data_value_anydata).compare_implementation(a_actual, get_exclude_xpath(), get_include_xpath()); elsif self.expected is of (ut_data_value_refcursor) then l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); - l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, - get_unordered(), false, false, get_join_by_list() ); + l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, get_unordered(), false, false, get_join_by_list() ); else l_result := equal_with_nulls((self.expected = a_actual), a_actual); end if; @@ -289,7 +287,7 @@ create or replace type body ut_equal as l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); l_result := 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() - || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).diff(l_actual, get_exclude_xpath(), get_include_xpath(), get_join_by_xpath(), get_unordered(),get_join_by_list()); + || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).filter_cursor(exclude_list, include_list).diff(l_actual, get_unordered(),get_join_by_list()); else l_result := 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index 7859e24ff..07ba65f5d 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -78,7 +78,7 @@ create or replace type body ut_include as l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); l_result := 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() - || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(self.exclude_list, self.include_list).diff(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), true); + || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(self.exclude_list, self.include_list).diff(l_actual, true, self.get_join_by_list()); else l_result := 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 06b8cbf17..8775b764c 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -409,20 +409,27 @@ create or replace package body test_expectations_cursor is as l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; - l_error_code integer := -31011; --xpath_error + l_actual_message varchar2(32767); + l_expected_message varchar2(32767); begin --Arrange open l_actual for select rownum as rn, 'a' as "A_Column", 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 4; open l_expected for select rownum as rn, 'a' as "A_Column", 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; - begin --Act - ut3.ut.expect(l_actual).to_equal(l_expected, a_exclude=>'/ROW/A_COLUMN,\\//Some_Col'); + ut3.ut.expect(l_actual).to_equal(l_expected, a_exclude=>'/ROW/A_COLUMN,\\//Some_Col'); --Assert - ut.fail('Expected '||l_error_code||' but nothing was raised'); - exception - when others then - ut.expect(sqlcode).to_equal(l_error_code); - end; + l_expected_message := q'[Actual: refcursor [ count = 3 ] was expected to equal: refcursor [ count = 3 ] +%Diff: +%Rows: [ 3 differences ] +%Row No. 1 - Actual: d +%Row No. 1 - Expected: c +%Row No. 2 - Actual: d +%Row No. 2 - Expected: c +%Row No. 3 - Actual: d +%Row No. 3 - Expected: c]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); end; procedure exclude_columns_xpath @@ -1003,44 +1010,7 @@ Rows: [ 4 differences ] --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; - - - procedure include_col_name_implicit is - l_actual SYS_REFCURSOR; - l_expected SYS_REFCURSOR; - begin - --Arrange - open l_actual for select rownum as rn, 'a', 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 4; - open l_expected for select rownum as rn, 'a', 'd' as A_COLUMN, 'c' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; - begin - --Act - ut3.ut.expect(l_actual).to_equal(l_expected).include(q'!/ROW/RN,'a',//SOME_COL!'); - --Assert - ut.fail('Expected exception but nothing was raised'); - exception - when others then - ut.expect(sqlcode).to_be_between(-31013,-31011); - end; - end; - - procedure exclude_col_name_implicit is - l_actual SYS_REFCURSOR; - l_expected SYS_REFCURSOR; - begin - --Arrange - open l_actual for select rownum as rn, 'a', 'c' as A_COLUMN, 'x' SOME_COL, 'd' "Some_Col" from dual a connect by level < 4; - open l_expected for select rownum as rn, 'a', 'd' as A_COLUMN, 'x' SOME_COL, 'c' "Some_Col" from dual a connect by level < 4; - begin - --Act - ut3.ut.expect(l_actual).to_equal(l_expected).exclude(q'!/ROW/RN,'a',//SOME_COL!'); - --Assert - ut.fail('Expected exception but nothing was raised'); - exception - when others then - ut.expect(sqlcode).to_be_between(-31013,-31011); - end; - end; - + procedure cursor_unorderd_compr_success is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index cbb029b9b..ce02623dd 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -92,7 +92,7 @@ create or replace package test_expectations_cursor is --%test(Excludes comma separated list of mixed columns and XPath) procedure exclude_columns_as_mix_csv_lst; - --%test(Exclude columns fails on invalid XPath) + --%test(Exclude column with invalid filter will result in column being included ) procedure exclude_columns_xpath_invalid; --%test(Exclude columns by XPath is case sensitive) @@ -193,12 +193,6 @@ create or replace package test_expectations_cursor is --%test(Reports column match on cursor with column name implicit ) procedure col_mtch_on_col_name_implicit; - --%test( Fail on passing implicit column name as include filter ) - procedure include_col_name_implicit; - - --%test( Fail on passing implicit column name as exclude filter ) - procedure exclude_col_name_implicit; - --%test( Compare cursors using unordered method success) procedure cursor_unorderd_compr_success; From 3759e90cffdd1bbc3a787031888622d3df04ed43 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Mon, 26 Nov 2018 12:51:28 +0000 Subject: [PATCH 62/83] Phase 2. Removal of x path and clean-up deprecated code --- .../data_values/ut_compound_data_helper.pkb | 213 ++++++------ .../data_values/ut_compound_data_helper.pks | 23 +- .../data_values/ut_compound_data_value.tpb | 5 +- .../ut_curr_usr_compound_helper.pkb | 310 ------------------ .../ut_curr_usr_compound_helper.pks | 24 -- .../data_values/ut_cursor_column.tpb | 2 +- .../data_values/ut_cursor_details.tpb | 8 +- .../data_values/ut_data_value_refcursor.tpb | 14 +- .../data_values/ut_data_value_refcursor.tps | 21 +- source/install.sql | 2 - source/uninstall_objects.sql | 2 - .../expectations/test_expectations_cursor.pkb | 12 +- 12 files changed, 140 insertions(+), 496 deletions(-) delete mode 100644 source/expectations/data_values/ut_curr_usr_compound_helper.pkb delete mode 100644 source/expectations/data_values/ut_curr_usr_compound_helper.pks diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 6033322dc..960da59a1 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -20,23 +20,10 @@ create or replace package body ut_compound_data_helper is g_diff_count integer; g_filter_tab ut_varchar2_list; - function get_column_info_xml(a_column_details ut_key_anyval_pair) return xmltype is - l_result varchar2(4000); - l_res xmltype; - l_data ut_data_value := a_column_details.value; - l_key varchar2(4000) := ut_utils.xmlgen_escaped_string(a_column_details.KEY); - l_is_diff number; - begin - l_result := '<'||l_key||' xml_valid_name="'||l_key; - if l_data is of(ut_data_value_xmltype) then - l_result := l_result||'" sql_diffable="0">' ||trim( both '''' from (treat(l_data as ut_data_value_xmltype).to_string)); - else - l_is_diff := ut_curr_usr_compound_helper.is_sql_compare_int((treat(l_data as ut_data_value_varchar2).data_value)); - l_result := l_result||'" sql_diffable="'||l_is_diff||'">' || ut_utils.xmlgen_escaped_string((treat(l_data as ut_data_value_varchar2).data_value)); - end if; - l_result := l_result ||''; - return xmltype(l_result); - end; + type t_type_name_map is table of varchar2(100) index by binary_integer; + g_type_name_map t_type_name_map; + g_anytype_name_map t_type_name_map; + g_anytype_collection_name t_type_name_map; function get_columns_filter( a_exclude_xpath varchar2, a_include_xpath varchar2, @@ -60,32 +47,6 @@ create or replace package body ut_compound_data_helper is return l_filter; end; - /** - * Current get column filter shaving off ROW tag during extract, this not working well with include and XMLTABLE option - * so when there is extract we artificially inject removed tag - **/ - function get_columns_row_filter( - a_exclude_xpath varchar2, a_include_xpath varchar2, - a_table_alias varchar2 := 'ucd', a_column_alias varchar2 := 'item_data' - ) return varchar2 is - l_filter varchar2(32767); - l_source_column varchar2(500) := a_table_alias||'.'||a_column_alias; - begin - -- this SQL statement is constructed in a way that we always get the same number and ordering of substitution variables - -- That is, we always get: l_exclude_xpath, l_include_xpath - -- regardless if the variables are NULL (not to be used) or NOT NULL and will be used for filtering - if a_exclude_xpath is null and a_include_xpath is null then - l_filter := ':l_exclude_xpath, :l_include_xpath, '||l_source_column||' as '||a_column_alias; - elsif a_exclude_xpath is not null and a_include_xpath is null then - l_filter := 'deletexml( '||l_source_column||', :l_exclude_xpath ) as '||a_column_alias||', :l_include_xpath'; - elsif a_exclude_xpath is null and a_include_xpath is not null then - l_filter := ':l_exclude_xpath, xmlelement("ROW",extract( '||l_source_column||', :l_include_xpath )) as '||a_column_alias; - elsif a_exclude_xpath is not null and a_include_xpath is not null then - l_filter := 'xmlelement("ROW",extract( deletexml( '||l_source_column||', :l_exclude_xpath ), :l_include_xpath )) as '||a_column_alias; - end if; - return l_filter; - end; - function get_columns_diff(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab) return tt_column_diffs is l_column_filter varchar2(32767); @@ -295,8 +256,8 @@ create or replace package body ut_compound_data_helper is end if; end; - function gen_compare_sql(a_column_info xmltype,a_inclusion_type boolean, a_is_negated boolean,a_unordered boolean, - a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob is + function gen_compare_sql(a_inclusion_type boolean, a_is_negated boolean,a_unordered boolean, + a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob is l_compare_sql clob; l_temp_string varchar2(32767); @@ -428,7 +389,6 @@ create or replace package body ut_compound_data_helper is return l_column_list; end; - function get_rows_diff_by_sql(a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_join_by_list ut_varchar2_list, a_unordered boolean @@ -608,65 +568,6 @@ create or replace package body ut_compound_data_helper is return dbms_utility.get_hash_value(a_string,a_base,a_size); end; - function columns_hash( - a_data_value_cursor ut_data_value_refcursor, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_hash_type binary_integer := dbms_crypto.hash_sh1 - ) return t_hash is - l_cols_hash t_hash; - begin - if not a_data_value_cursor.is_null then - execute immediate - q'[select dbms_crypto.hash(replace(x.item_data.getclobval(),'>CHAR<','>VARCHAR2<'),]'||a_hash_type||') ' || - ' from ( select '||get_columns_filter(a_exclude_xpath, a_include_xpath)|| - ' from (select :columns_info as item_data from dual ) ucd' || - ' ) x' - into l_cols_hash using a_exclude_xpath,a_include_xpath, a_data_value_cursor.columns_info; - end if; - return l_cols_hash; - end; - - function is_pk_exists(a_expected_cursor xmltype,a_actual_cursor xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2,a_join_by_xpath varchar2) - return tt_missing_pk is - l_pk_xpath_tabs ut_varchar2_list := ut_varchar2_list(); - l_column_filter varchar2(32767); - l_no_missing_keys tt_missing_pk := tt_missing_pk(); - - begin - if a_join_by_xpath is not null then - l_pk_xpath_tabs := ut_utils.string_to_table(a_join_by_xpath,'|'); - l_column_filter := get_columns_row_filter(a_exclude_xpath, a_include_xpath); - - execute immediate q'[ - with xpaths_tab as (select column_value xpath from table(:xpath_tabs)), - expected_column_info as ( select :expected as item_data from dual ), - actual_column_info as ( select :actual as item_data from dual ) - select REGEXP_SUBSTR (xpath,'[^(/\*/)](.+)$'),diif_type from - ( - (select xpath,'e' diif_type from xpaths_tab - minus - select xpath,'e' diif_type - from ( select ]'||l_column_filter||q'[ from expected_column_info ucd) x - ,xpaths_tab - where xmlexists (xpaths_tab.xpath passing x.item_data) - ) - union all - (select xpath,'a' diif_type from xpaths_tab - minus - select xpath,'a' diif_type - from ( select ]'||l_column_filter||q'[ from actual_column_info ucd) x - ,xpaths_tab - where xmlexists (xpaths_tab.xpath passing x.item_data) - ) - )]' bulk collect into l_no_missing_keys - using l_pk_xpath_tabs,a_expected_cursor,a_actual_cursor, - a_exclude_xpath, a_include_xpath, - a_exclude_xpath, a_include_xpath; - - end if; - - return l_no_missing_keys; - end; - procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw) is begin forall idx in 1..a_diff_tab.count @@ -853,6 +754,106 @@ create or replace package body ut_compound_data_helper is end loop; return l_warn_msg; end; + + function getxmlchildren(p_parent_name varchar2,a_cursor_table ut_cursor_column_tab) + return xmltype is + l_result xmltype; + begin + + select xmlagg(xmlelement(evalname t.column_name,t.column_type, + getxmlchildren(t.column_name,a_cursor_table))) + into l_result + from table(a_cursor_table) t + where (p_parent_name is not null and parent_name = p_parent_name) + or (p_parent_name is null and parent_name is null) + having count(*) > 0; + + + return l_result; + end; + + function is_sql_compare_allowed(a_type_name varchar2) return boolean is + begin + --clob/blob/xmltype/object/nestedcursor/nestedtable + if a_type_name IN (g_type_name_map(dbms_sql.blob_type), + g_type_name_map(dbms_sql.clob_type), + g_type_name_map(dbms_sql.bfile_type), + g_anytype_name_map(dbms_types.typecode_namedcollection)) + then + return false; + else + return true; + end if; + end; + + function is_collection (a_owner varchar2,a_type_name varchar2, a_anytype_code in integer :=null) return boolean is + l_type_view varchar2(200) := ut_metadata.get_dba_view('dba_types'); + l_typecode varchar2(100); + begin + if a_anytype_code is null then + execute immediate 'select typecode from '||l_type_view ||' + where owner = :owner and type_name = :typename' + into l_typecode using a_owner,a_type_name; + + return l_typecode = 'COLLECTION'; + else + return a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection); + end if; + + exception + when no_data_found then + return false; + end; + + function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is + begin + return case when a_dbms_sql_desc then g_type_name_map(a_type_code) else g_anytype_name_map(a_type_code) end; + end; + + +begin + g_anytype_name_map(dbms_types.typecode_date) := 'DATE'; + g_anytype_name_map(dbms_types.typecode_number) := 'NUMBER'; + g_anytype_name_map(dbms_types.typecode_raw) := 'RAW'; + g_anytype_name_map(dbms_types.typecode_char) := 'CHAR'; + g_anytype_name_map(dbms_types.typecode_varchar2) := 'VARCHAR2'; + g_anytype_name_map(dbms_types.typecode_varchar) := 'VARCHAR'; + g_anytype_name_map(dbms_types.typecode_blob) := 'BLOB'; + g_anytype_name_map(dbms_types.typecode_bfile) := 'BFILE'; + g_anytype_name_map(dbms_types.typecode_clob) := 'CLOB'; + g_anytype_name_map(dbms_types.typecode_timestamp) := 'TIMESTAMP'; + g_anytype_name_map(dbms_types.typecode_timestamp_tz) := 'TIMESTAMP WITH TIME ZONE'; + g_anytype_name_map(dbms_types.typecode_timestamp_ltz) := 'TIMESTAMP WITH LOCAL TIME ZONE'; + g_anytype_name_map(dbms_types.typecode_interval_ym) := 'INTERVAL YEAR TO MONTH'; + g_anytype_name_map(dbms_types.typecode_interval_ds) := 'INTERVAL DAY TO SECOND'; + g_anytype_name_map(dbms_types.typecode_bfloat) := 'BINARY_FLOAT'; + g_anytype_name_map(dbms_types.typecode_bdouble) := 'BINARY_DOUBLE'; + g_anytype_name_map(dbms_types.typecode_urowid) := 'UROWID'; + g_anytype_name_map(dbms_types.typecode_varray) := 'VARRRAY'; + g_anytype_name_map(dbms_types.typecode_table) := 'TABLE'; + g_anytype_name_map(dbms_types.typecode_namedcollection) := 'NAMEDCOLLECTION'; + + g_type_name_map( dbms_sql.binary_bouble_type ) := 'BINARY_DOUBLE'; + g_type_name_map( dbms_sql.bfile_type ) := 'BFILE'; + g_type_name_map( dbms_sql.binary_float_type ) := 'BINARY_FLOAT'; + g_type_name_map( dbms_sql.blob_type ) := 'BLOB'; + g_type_name_map( dbms_sql.long_raw_type ) := 'LONG RAW'; + g_type_name_map( dbms_sql.char_type ) := 'CHAR'; + g_type_name_map( dbms_sql.clob_type ) := 'CLOB'; + g_type_name_map( dbms_sql.long_type ) := 'LONG'; + g_type_name_map( dbms_sql.date_type ) := 'DATE'; + g_type_name_map( dbms_sql.interval_day_to_second_type ) := 'INTERVAL DAY TO SECOND'; + g_type_name_map( dbms_sql.interval_year_to_month_type ) := 'INTERVAL YEAR TO MONTH'; + g_type_name_map( dbms_sql.raw_type ) := 'RAW'; + g_type_name_map( dbms_sql.timestamp_type ) := 'TIMESTAMP'; + g_type_name_map( dbms_sql.timestamp_with_tz_type ) := 'TIMESTAMP WITH TIME ZONE'; + g_type_name_map( dbms_sql.timestamp_with_local_tz_type ) := 'TIMESTAMP WITH LOCAL TIME ZONE'; + g_type_name_map( dbms_sql.varchar2_type ) := 'VARCHAR2'; + g_type_name_map( dbms_sql.number_type ) := 'NUMBER'; + g_type_name_map( dbms_sql.rowid_type ) := 'ROWID'; + g_type_name_map( dbms_sql.urowid_type ) := 'UROWID'; + g_type_name_map( dbms_sql.user_defined_type ) := 'USER_DEFINED_TYPE'; + g_type_name_map( dbms_sql.ref_type ) := 'REF_TYPE'; -end; +end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 50d70974d..5e8671d13 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -58,9 +58,6 @@ create or replace package ut_compound_data_helper authid definer is type t_diff_tab is table of t_diff_rec; - - function get_column_info_xml(a_column_details ut_key_anyval_pair) return xmltype; - function get_columns_filter( a_exclude_xpath varchar2, a_include_xpath varchar2, a_table_alias varchar2 := 'ucd', a_column_alias varchar2 := 'item_data' @@ -87,17 +84,9 @@ create or replace package ut_compound_data_helper authid definer is function get_hash(a_data clob, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash; function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer :=30) return number; - - function columns_hash( - a_data_value_cursor ut_data_value_refcursor, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_hash_type binary_integer := dbms_crypto.hash_sh1 - ) return t_hash; - - function is_pk_exists(a_expected_cursor xmltype, a_actual_cursor xmltype, a_exclude_xpath varchar2, a_include_xpath varchar2,a_join_by_xpath varchar2) - return tt_missing_pk; - function gen_compare_sql(a_column_info xmltype, a_inclusion_type boolean, a_is_negated boolean, a_unordered boolean, - a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob; + function gen_compare_sql(a_inclusion_type boolean, a_is_negated boolean, a_unordered boolean, + a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob; procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw); @@ -127,5 +116,13 @@ create or replace package ut_compound_data_helper authid definer is function generate_missing_cols_warn_msg(a_missing_columns ut_varchar2_list,a_attribute in varchar2) return varchar2; + function getxmlchildren(p_parent_name varchar2,a_cursor_table ut_cursor_column_tab) return xmltype; + + function is_sql_compare_allowed(a_type_name varchar2) return boolean; + + function is_collection (a_owner varchar2,a_type_name varchar2, a_anytype_code in integer :=null) return boolean; + + function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2; + end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index a1cb14993..a06ac1d14 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -219,9 +219,8 @@ create or replace type body ut_compound_data_value as l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - open l_loop_curs for ut_compound_data_helper.gen_compare_sql(treat(a_other as ut_data_value_refcursor).col_info_desc, - a_inclusion_compare, a_is_negated, a_unordered, treat(a_other as ut_data_value_refcursor), - a_join_by_list ) using self.data_id,l_other.data_id; + open l_loop_curs for ut_compound_data_helper.gen_compare_sql(a_inclusion_compare, a_is_negated, a_unordered, + treat(a_other as ut_data_value_refcursor), a_join_by_list ) using self.data_id,l_other.data_id; loop fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; exit when l_diff_tab.count = 0; diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb b/source/expectations/data_values/ut_curr_usr_compound_helper.pkb deleted file mode 100644 index 8c7b53c92..000000000 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pkb +++ /dev/null @@ -1,310 +0,0 @@ -create or replace package body ut_curr_usr_compound_helper is - - type t_type_name_map is table of varchar2(100) index by binary_integer; - g_type_name_map t_type_name_map; - g_anytype_name_map t_type_name_map; - g_anytype_collection_name t_type_name_map; - g_user_defined_type pls_integer := dbms_sql.user_defined_type; - g_is_collection boolean := false; - - procedure set_collection_state(a_is_collection boolean) is - begin - --Make sure that we set a g_is_collection only once so we dont reset from true to false. - if not g_is_collection then - g_is_collection := a_is_collection; - end if; - end; - - function is_sql_compare_allowed(a_type_name varchar2) return boolean is - begin - --clob/blob/xmltype/object/nestedcursor/nestedtable - if a_type_name IN (g_type_name_map(dbms_sql.blob_type), - g_type_name_map(dbms_sql.clob_type), - g_type_name_map(dbms_sql.bfile_type), - g_anytype_name_map(dbms_types.typecode_namedcollection)) - then - return false; - else - return true; - end if; - end; - - function is_sql_compare_int(a_type_name varchar2) return integer is - begin - return ut_utils.boolean_to_int(is_sql_compare_allowed(a_type_name)); - end; - - function is_collection (a_owner varchar2,a_type_name varchar2, a_anytype_code in integer :=null) return boolean is - l_type_view varchar2(200) := ut_metadata.get_dba_view('dba_types'); - l_typecode varchar2(100); - begin - - if a_anytype_code is null then - - execute immediate 'select typecode from '||l_type_view ||' - where owner = :owner and type_name = :typename' - into l_typecode using a_owner,a_type_name; - - return l_typecode = 'COLLECTION'; - else - return a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection); - end if; - - exception - when no_data_found then - return false; - end; - - function get_column_type(a_desc_rec dbms_sql.desc_rec3, a_desc_user_types boolean := false) return ut_key_anyval_pair is - l_data ut_data_value; - l_result ut_key_anyval_pair; - l_data_type varchar2(500) := 'unknown datatype'; - - begin - - if g_type_name_map.exists(a_desc_rec.col_type) then - l_data := ut_data_value_varchar2(g_type_name_map(a_desc_rec.col_type)); - return ut_key_anyval_pair(a_desc_rec.col_name,l_data); - end if; - - /*If its a collection regardless is we want to describe user defined types we will return just a name - and capture that name */ - if a_desc_rec.col_type = g_user_defined_type and is_collection(a_desc_rec.col_schema_name,a_desc_rec.col_type_name) then - l_data := ut_data_value_varchar2(a_desc_rec.col_schema_name||'.'||a_desc_rec.col_type_name); - set_collection_state(true); - return ut_key_anyval_pair(a_desc_rec.col_name,l_data); - end if; - - if a_desc_rec.col_type = g_user_defined_type and a_desc_user_types then - if a_desc_rec.col_type_name = 'XMLTYPE' then - l_data := ut_data_value_varchar2(a_desc_rec.col_type_name); - else - --This is only time we return xml if its user defined. This is important as its used later. - l_data :=ut_data_value_xmltype(get_user_defined_type(a_desc_rec.col_schema_name,a_desc_rec.col_type_name)); - end if; - return ut_key_anyval_pair(a_desc_rec.col_name,l_data); - end if; - - if a_desc_rec.col_schema_name is not null and a_desc_rec.col_type_name is not null then - l_data := ut_data_value_varchar2(a_desc_rec.col_schema_name||'.'||a_desc_rec.col_type_name); - return ut_key_anyval_pair(a_desc_rec.col_name,l_data); - end if; - end; - - function get_columns_info( - a_columns_tab dbms_sql.desc_tab3, a_columns_count integer, a_desc_user_types boolean := false - ) return ut_key_anyval_pairs is - l_result ut_key_anyval_pairs := ut_key_anyval_pairs(); - begin - for i in 1 .. a_columns_count loop - l_result.extend; - l_result(l_result.last) := get_column_type(a_columns_tab(i),a_desc_user_types); - end loop; - - return l_result; - end; - - procedure get_descr_cursor( - a_cursor in out nocopy sys_refcursor, - a_columns_tab in out nocopy ut_key_anyval_pairs, - a_join_by_tab in out nocopy ut_key_anyval_pairs - ) is - l_cursor_number integer; - l_columns_count pls_integer; - l_columns_desc dbms_sql.desc_tab3; - begin - if a_cursor is null or not a_cursor%isopen then - a_columns_tab := null; - a_join_by_tab := null; - end if; - l_cursor_number := dbms_sql.to_cursor_number( a_cursor ); - dbms_sql.describe_columns3( l_cursor_number, l_columns_count, l_columns_desc ); - a_cursor := dbms_sql.to_refcursor( l_cursor_number ); - a_columns_tab := get_columns_info( l_columns_desc, l_columns_count, true); - a_join_by_tab := get_columns_info( l_columns_desc, l_columns_count, true); - end; - - procedure get_columns_info( - a_cursor in out nocopy sys_refcursor, - a_columns_info out nocopy xmltype, - a_join_by_info out nocopy xmltype, - a_contains_collection out nocopy number - ) is - l_columns_info xmltype; - l_join_by_info xmltype; - l_result_tmp xmltype; - l_columns_tab ut_key_anyval_pairs; - l_join_by_tab ut_key_anyval_pairs; - begin - - get_descr_cursor(a_cursor,l_columns_tab,l_join_by_tab); - - for i in 1..l_columns_tab.COUNT - loop - l_result_tmp := ut_compound_data_helper.get_column_info_xml(l_columns_tab(i)); - select xmlconcat(l_columns_info,l_result_tmp) into l_columns_info from dual; - end loop; - - for i in 1..l_join_by_tab.COUNT - loop - l_result_tmp := ut_compound_data_helper.get_column_info_xml(l_join_by_tab(i)); - select xmlconcat(l_join_by_info,l_result_tmp) into l_join_by_info from dual; - end loop; - - select XMLELEMENT("ROW",l_columns_info ),XMLELEMENT("ROW",l_join_by_info ) - into a_columns_info,a_join_by_info from dual; - - a_contains_collection := ut_utils.boolean_to_int(g_is_collection); - end; - - function get_anytype_attribute_count (a_anytype anytype) return pls_integer is - l_attribute_typecode pls_integer; - l_schema_name varchar2(32767); - l_version varchar2(32767); - l_type_name varchar2(32767); - l_attributes pls_integer; - l_prec pls_integer; - l_scale pls_integer; - l_len pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - begin - l_attribute_typecode := a_anytype.getinfo( - prec => l_prec, - scale => l_scale, - len => l_len, - csid => l_csid, - csfrm => l_csfrm, - schema_name => l_schema_name, - type_name => l_type_name, - version => l_version, - numelems => l_attributes); - return l_attributes; - end; - - function get_anytype_attributes_info (a_anytype anytype) return ut_key_value_pairs is - l_result ut_key_value_pairs := ut_key_value_pairs(); - l_attribute_typecode pls_integer; - l_aname varchar2(32767); - l_prec pls_integer; - l_scale pls_integer; - l_len pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - l_attr_elt_type anytype; - l_attributes_cnt pls_integer; - begin - l_attributes_cnt := NVL(get_anytype_attribute_count(a_anytype),0); - - if l_attributes_cnt > 0 then - for i in 1..get_anytype_attribute_count(a_anytype) loop - l_attribute_typecode := a_anytype.getAttrElemInfo( - pos => i, --First attribute - prec => l_prec, - scale => l_scale, - len => l_len, - csid => l_csid, - csfrm => l_csfrm, - attr_elt_type => l_attr_elt_type, - aname => l_aname); - - l_result.extend; - l_result(l_result.last) := ut_key_value_pair(l_aname, g_anytype_name_map(l_attribute_typecode)); - --check for collection - if g_anytype_collection_name.exists(l_attribute_typecode) then - set_collection_state(true); - end if; - end loop; - end if; - - return l_result; - end; - - function get_user_defined_type(a_owner varchar2,a_type_name varchar2) return xmltype is - l_anydata anydata; - l_anytype anytype; - l_typecode pls_integer; - l_result xmltype; - l_columns_tab ut_key_value_pairs := ut_key_value_pairs(); - begin - execute immediate 'declare - l_v '||a_owner||'.'||a_type_name||'; - begin - :anydata := anydata.convertobject(l_v); - end;' USING IN OUT l_anydata; - - l_typecode := l_anydata.gettype(l_anytype); - l_columns_tab := get_anytype_attributes_info(l_anytype); - - select xmlagg(xmlelement(evalname key,value)) - into l_result from table(l_columns_tab); - - return l_result; - end; - - function extract_min_col_info(a_full_col_info xmltype) return xmltype is - l_result xmltype; - begin - SELECT deleteXML(a_full_col_info,'/ROW/*/@sql_diffable') - into l_result - from dual; - return l_result ; - end; - - function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is - begin - return case when a_dbms_sql_desc then g_type_name_map(a_type_code) else g_anytype_name_map(a_type_code) end; - end; - - begin - g_anytype_name_map(dbms_types.typecode_date) := 'DATE'; - g_anytype_name_map(dbms_types.typecode_number) := 'NUMBER'; - g_anytype_name_map(dbms_types.typecode_raw) := 'RAW'; - g_anytype_name_map(dbms_types.typecode_char) := 'CHAR'; - g_anytype_name_map(dbms_types.typecode_varchar2) := 'VARCHAR2'; - g_anytype_name_map(dbms_types.typecode_varchar) := 'VARCHAR'; - g_anytype_name_map(dbms_types.typecode_blob) := 'BLOB'; - g_anytype_name_map(dbms_types.typecode_bfile) := 'BFILE'; - g_anytype_name_map(dbms_types.typecode_clob) := 'CLOB'; - g_anytype_name_map(dbms_types.typecode_timestamp) := 'TIMESTAMP'; - g_anytype_name_map(dbms_types.typecode_timestamp_tz) := 'TIMESTAMP WITH TIME ZONE'; - g_anytype_name_map(dbms_types.typecode_timestamp_ltz) := 'TIMESTAMP WITH LOCAL TIME ZONE'; - g_anytype_name_map(dbms_types.typecode_interval_ym) := 'INTERVAL YEAR TO MONTH'; - g_anytype_name_map(dbms_types.typecode_interval_ds) := 'INTERVAL DAY TO SECOND'; - g_anytype_name_map(dbms_types.typecode_bfloat) := 'BINARY_FLOAT'; - g_anytype_name_map(dbms_types.typecode_bdouble) := 'BINARY_DOUBLE'; - g_anytype_name_map(dbms_types.typecode_urowid) := 'UROWID'; - g_anytype_name_map(dbms_types.typecode_varray) := 'VARRRAY'; - g_anytype_name_map(dbms_types.typecode_table) := 'TABLE'; - g_anytype_name_map(dbms_types.typecode_namedcollection) := 'NAMEDCOLLECTION'; - - g_anytype_collection_name(dbms_types.typecode_varray) := 'VARRRAY'; - g_anytype_collection_name(dbms_types.typecode_table) := 'TABLE'; - g_anytype_collection_name(dbms_types.typecode_namedcollection) := 'NAMEDCOLLECTION'; - - - g_type_name_map( dbms_sql.binary_bouble_type ) := 'BINARY_DOUBLE'; - g_type_name_map( dbms_sql.bfile_type ) := 'BFILE'; - g_type_name_map( dbms_sql.binary_float_type ) := 'BINARY_FLOAT'; - g_type_name_map( dbms_sql.blob_type ) := 'BLOB'; - g_type_name_map( dbms_sql.long_raw_type ) := 'LONG RAW'; - g_type_name_map( dbms_sql.char_type ) := 'CHAR'; - g_type_name_map( dbms_sql.clob_type ) := 'CLOB'; - g_type_name_map( dbms_sql.long_type ) := 'LONG'; - g_type_name_map( dbms_sql.date_type ) := 'DATE'; - g_type_name_map( dbms_sql.interval_day_to_second_type ) := 'INTERVAL DAY TO SECOND'; - g_type_name_map( dbms_sql.interval_year_to_month_type ) := 'INTERVAL YEAR TO MONTH'; - g_type_name_map( dbms_sql.raw_type ) := 'RAW'; - g_type_name_map( dbms_sql.timestamp_type ) := 'TIMESTAMP'; - g_type_name_map( dbms_sql.timestamp_with_tz_type ) := 'TIMESTAMP WITH TIME ZONE'; - g_type_name_map( dbms_sql.timestamp_with_local_tz_type ) := 'TIMESTAMP WITH LOCAL TIME ZONE'; - g_type_name_map( dbms_sql.varchar2_type ) := 'VARCHAR2'; - g_type_name_map( dbms_sql.number_type ) := 'NUMBER'; - g_type_name_map( dbms_sql.rowid_type ) := 'ROWID'; - g_type_name_map( dbms_sql.urowid_type ) := 'UROWID'; - g_type_name_map( dbms_sql.user_defined_type ) := 'USER_DEFINED_TYPE'; - g_type_name_map( dbms_sql.ref_type ) := 'REF_TYPE'; - - -end; -/ diff --git a/source/expectations/data_values/ut_curr_usr_compound_helper.pks b/source/expectations/data_values/ut_curr_usr_compound_helper.pks deleted file mode 100644 index 71427b686..000000000 --- a/source/expectations/data_values/ut_curr_usr_compound_helper.pks +++ /dev/null @@ -1,24 +0,0 @@ -create or replace package ut_curr_usr_compound_helper authid current_user is - - function is_sql_compare_allowed(a_type_name varchar2) return boolean; - - function is_sql_compare_int(a_type_name varchar2) return integer; - - function is_collection (a_owner varchar2,a_type_name varchar2, a_anytype_code in integer :=null) return boolean; - - --TODO Depracate once switch fully to type - procedure get_columns_info( - a_cursor in out nocopy sys_refcursor, - a_columns_info out nocopy xmltype, - a_join_by_info out nocopy xmltype, - a_contains_collection out nocopy number - ); - - function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return xmltype; - - function extract_min_col_info(a_full_col_info xmltype) return xmltype; - - function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2; - -end; -/ diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index aba9236cc..a5ae42e62 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -26,7 +26,7 @@ create or replace type body ut_cursor_column as self.is_sql_diffable := case when lower(self.column_type) = 'user_defined_type' then 0 else - ut_utils.boolean_to_int(ut_curr_usr_compound_helper.is_sql_compare_allowed(self.column_type)) + ut_utils.boolean_to_int(ut_compound_data_helper.is_sql_compare_allowed(self.column_type)) end; --TODO : Part of the constructor same as has nested ?? self.is_collection := a_collection; diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index 7323d7e13..1c491ab84 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -82,7 +82,7 @@ create or replace type body ut_cursor_details as a_cursor := dbms_sql.to_refcursor(l_cursor_number); for cur in 1 .. l_columns_count loop - l_is_collection := ut_curr_usr_compound_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name); + l_is_collection := ut_compound_data_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name); self.cursor_info.extend; self.cursor_info(cursor_info.last) := ut_cursor_column( l_columns_desc(cur).col_name, l_columns_desc(cur).col_schema_name, @@ -93,7 +93,7 @@ create or replace type body ut_cursor_details as null, 1, cur, - ut_curr_usr_compound_helper.get_column_type_desc(l_columns_desc(cur).col_type,true), + ut_compound_data_helper.get_column_type_desc(l_columns_desc(cur).col_type,true), ut_utils.boolean_to_int(l_is_collection) ); if l_columns_desc(cur).col_type = dbms_sql.user_defined_type and not l_is_collection then @@ -108,7 +108,7 @@ create or replace type body ut_cursor_details as attr_elt_type => l_attr_elt_type, aname => l_aname); - l_is_collection := ut_curr_usr_compound_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name,l_attribute_typecode); + l_is_collection := ut_compound_data_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name,l_attribute_typecode); self.cursor_info.extend; self.cursor_info(cursor_info.last) := ut_cursor_column( l_aname, l_columns_desc(cur).col_schema_name, @@ -119,7 +119,7 @@ create or replace type body ut_cursor_details as l_columns_desc(cur).col_name, 2, i, - ut_curr_usr_compound_helper.get_column_type_desc(l_attribute_typecode,false), + ut_compound_data_helper.get_column_type_desc(l_attribute_typecode,false), ut_utils.boolean_to_int(l_is_collection) ); end loop; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 06fe0fdc9..f3fc6ff0f 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -42,11 +42,8 @@ create or replace type body ut_data_value_refcursor as if l_cursor is not null then if l_cursor%isopen then --Get some more info regarding cursor, including if it containts collection columns and what is their name - - ut_curr_usr_compound_helper.get_columns_info(l_cursor,self.col_info_desc,self.key_info, - self.contain_collection); + self.elements_count := 0; - self.columns_info := ut_curr_usr_compound_helper.extract_min_col_info(self.col_info_desc); self.cursor_details := ut_cursor_details(l_cursor); -- We use DBMS_XMLGEN in order to: -- 1) be able to process data in bulks (set of rows) @@ -103,12 +100,19 @@ create or replace type body ut_data_value_refcursor as overriding member function to_string return varchar2 is l_result clob; l_result_string varchar2(32767); + l_cursor_details ut_cursor_column_tab := self.cursor_details.cursor_info; + + l_query varchar2(32767); + l_column_info xmltype; + begin if not self.is_null() then dbms_lob.createtemporary(l_result, true); ut_utils.append_to_clob(l_result, 'Data-types:'||chr(10)); - ut_utils.append_to_clob(l_result, self.columns_info.getclobval()); + + l_column_info := ut_compound_data_helper.getxmlchildren(null,l_cursor_details); + ut_utils.append_to_clob(l_result, l_column_info.getclobval()); ut_utils.append_to_clob(l_result,chr(10)||(self as ut_compound_data_value).to_string()); l_result_string := ut_utils.to_string(l_result,null); dbms_lob.freetemporary(l_result); diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index 2a6b58ba1..f2a748abd 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -24,26 +24,7 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( * Determines if the cursor is null */ is_cursor_null integer, - - /** - * hold information if the cursor contains collection object - */ - contain_collection number(1,0), - - /** - * Holds information about column names and column data-types - */ - columns_info xmltype, - - /** - * Holds information about column names and column data-types and also some supporting attributes - */ - col_info_desc xmltype, - /** - * Holds more detailed information regarding the pk joins - */ - key_info xmltype, - + /* *columns info */ diff --git a/source/install.sql b/source/install.sql index 1de0697b2..59283a5de 100644 --- a/source/install.sql +++ b/source/install.sql @@ -199,7 +199,6 @@ prompt Installing DBMSPLSQL Tables objects into &&ut3_owner schema @@install_component.sql 'expectations/data_values/ut_key_anyval_pair.tps' @@install_component.sql 'expectations/data_values/ut_key_anyval_pairs.tps' @@install_component.sql 'expectations/data_values/ut_compound_data_helper.pks' -@@install_component.sql 'expectations/data_values/ut_curr_usr_compound_helper.pks' @@install_component.sql 'expectations/matchers/ut_matcher.tps' @@install_component.sql 'expectations/matchers/ut_comparison_matcher.tps' @@install_component.sql 'expectations/matchers/ut_be_false.tps' @@ -224,7 +223,6 @@ prompt Installing DBMSPLSQL Tables objects into &&ut3_owner schema @@install_component.sql 'expectations/data_values/ut_data_value.tpb' @@install_component.sql 'expectations/data_values/ut_compound_data_value.tpb' @@install_component.sql 'expectations/data_values/ut_compound_data_helper.pkb' -@@install_component.sql 'expectations/data_values/ut_curr_usr_compound_helper.pkb' @@install_component.sql 'expectations/data_values/ut_data_value_anydata.tpb' @@install_component.sql 'expectations/data_values/ut_data_value_object.tpb' @@install_component.sql 'expectations/data_values/ut_data_value_collection.tpb' diff --git a/source/uninstall_objects.sql b/source/uninstall_objects.sql index f183ce30c..0475e347d 100644 --- a/source/uninstall_objects.sql +++ b/source/uninstall_objects.sql @@ -279,8 +279,6 @@ drop package ut_coverage_profiler; drop package ut_compound_data_helper; -drop package ut_curr_usr_compound_helper; - drop package ut_coverage_helper_profiler; drop type ut_have_count; diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 8775b764c..54dafd37a 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2365,11 +2365,11 @@ Diff:% --Assert l_expected_message := q'[%Actual: (refcursor [ count = % ])% %Data-types:% -%VARCHAR2NUMBER% +%VARCHAR2NUMBER% %Data:% %was expected not to include:(refcursor [ count = 1 ])% %Data-types:% -%CHARNUMBER% +%CHARNUMBER% %Data:% %TEST-600%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; @@ -2395,11 +2395,11 @@ Diff:% --Assert l_expected_message := q'[%Actual: (refcursor [ count = % ])% %Data-types:% -%VARCHAR2NUMBER% +%VARCHAR2NUMBER% %Data:% %was expected not to include:(refcursor [ count = 1 ])% %Data-types:% -%CHARNUMBER% +%CHARNUMBER% %Data:% %TEST-600%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; @@ -2449,12 +2449,12 @@ Diff:% --Assert l_expected_message := q'[%Actual: (refcursor [ count = 9 ]) %Data-types: -%NUMBERCHARCHARCHARCHAR +%NUMBERCHARCHARCHARCHAR %Data: %% %was expected not to include:(refcursor [ count = 3 ]) %Data-types: -%NUMBERCHARCHARCHARCHAR +%NUMBERCHARCHARCHARCHAR %Data: %1adxc2adxc3adxc]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; From 29fe2e195eeaffa95e6351f50089af84a1491e27 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Mon, 26 Nov 2018 20:37:23 +0000 Subject: [PATCH 63/83] Update stylecheck --- source/expectations/data_values/ut_compound_data_helper.pkb | 6 +++--- source/expectations/data_values/ut_compound_data_helper.pks | 2 +- 2 files changed, 4 insertions(+), 4 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 960da59a1..7d8f89158 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -755,7 +755,7 @@ create or replace package body ut_compound_data_helper is return l_warn_msg; end; - function getxmlchildren(p_parent_name varchar2,a_cursor_table ut_cursor_column_tab) + function getxmlchildren(a_parent_name varchar2,a_cursor_table ut_cursor_column_tab) return xmltype is l_result xmltype; begin @@ -764,8 +764,8 @@ create or replace package body ut_compound_data_helper is getxmlchildren(t.column_name,a_cursor_table))) into l_result from table(a_cursor_table) t - where (p_parent_name is not null and parent_name = p_parent_name) - or (p_parent_name is null and parent_name is null) + where (a_parent_name is not null and parent_name = a_parent_name) + or (a_parent_name is null and parent_name is null) having count(*) > 0; diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 5e8671d13..f4ab72856 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -116,7 +116,7 @@ create or replace package ut_compound_data_helper authid definer is function generate_missing_cols_warn_msg(a_missing_columns ut_varchar2_list,a_attribute in varchar2) return varchar2; - function getxmlchildren(p_parent_name varchar2,a_cursor_table ut_cursor_column_tab) return xmltype; + function getxmlchildren(a_parent_name varchar2,a_cursor_table ut_cursor_column_tab) return xmltype; function is_sql_compare_allowed(a_type_name varchar2) return boolean; From 1c0582b781d76a96d3936d35bd7cd99e90d2c122 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Mon, 26 Nov 2018 20:55:09 +0000 Subject: [PATCH 64/83] Update test time exec --- test/core/min_grant_user/test_min_grant_user.pkb | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/test/core/min_grant_user/test_min_grant_user.pkb b/test/core/min_grant_user/test_min_grant_user.pkb index 906906fe1..0955e6313 100644 --- a/test/core/min_grant_user/test_min_grant_user.pkb +++ b/test/core/min_grant_user/test_min_grant_user.pkb @@ -53,7 +53,7 @@ create or replace package body test_min_grant_user is execute immediate 'begin ut3$user#.test_cursor_grants.run(); end;'; l_results := core.get_dbms_output_as_clob(); --Assert - ut.expect( l_results ).to_be_like( '%execute join by test [.% sec]' || + ut.expect( l_results ).to_be_like( '%execute join by test [% sec]' || '%1 tests, 0 failed, 0 errored, 0 disabled, 0 warning(s)%' ); end; From 7837eb46fc3a119c8c6b6419cf0b1da608b4195b Mon Sep 17 00:00:00 2001 From: lwasylow Date: Wed, 28 Nov 2018 12:16:14 +0000 Subject: [PATCH 65/83] Anydata refactoring. --- .../data_values/ut_compound_data_helper.pkb | 4 +- .../data_values/ut_cursor_column.tpb | 11 +-- .../data_values/ut_cursor_column.tps | 8 +- .../data_values/ut_cursor_details.tpb | 74 ++++++++-------- .../data_values/ut_cursor_details.tps | 5 +- .../data_values/ut_data_value_refcursor.tpb | 86 ++++++++++--------- .../data_values/ut_data_value_refcursor.tps | 1 + 7 files changed, 96 insertions(+), 93 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 7d8f89158..5c2a881d3 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -623,7 +623,7 @@ create or replace package body ut_compound_data_helper is l_sql varchar2(32767) := get_cursor_vs_list_sql; l_result ut_cursor_column_tab := ut_cursor_column_tab(); begin - l_sql := l_sql || q'[select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name, i.column_prec,i.column_scale,i.column_len, i.parent_name, + l_sql := l_sql || q'[select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name,i.column_len, i.parent_name, i.hierarchy_level,i.column_position, i.column_type, i.is_collection) from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name)]'; if a_include then @@ -735,7 +735,7 @@ create or replace package body ut_compound_data_helper is function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list) return ut_cursor_column_tab is l_result ut_cursor_column_tab; begin - select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name, i.column_prec,i.column_scale,i.column_len, i.parent_name, + select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name,i.column_len, i.parent_name, i.hierarchy_level,i.column_position, i.column_type, i.is_collection) bulk collect into l_result from table(a_cursor_details) i diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index a5ae42e62..85241804f 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -2,16 +2,13 @@ create or replace type body ut_cursor_column as member procedure init(self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, - a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, a_col_position integer, a_col_type varchar2, a_collection integer) is begin self.parent_name := a_parent_name; self.hierarchy_level := a_hierarchy_level; self.column_position := a_col_position; - self.column_prec := a_col_prec; self.column_len := a_col_max_len; - self.column_scale := a_col_scale; self.column_name := TRIM( BOTH '''' FROM a_col_name); self.column_type_name := a_col_type_name; self.access_path := case when self.parent_name is null then self.column_name else self.parent_name||'/'||self.column_name end; @@ -41,12 +38,10 @@ create or replace type body ut_cursor_column as constructor function ut_cursor_column( self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, - a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, a_col_position integer, a_col_type in varchar2, a_collection integer) return self as result is begin - init(a_col_name, a_col_schema_name, a_col_type_name, a_col_prec, - a_col_scale, a_col_max_len, a_parent_name,a_hierarchy_level, a_col_position, a_col_type, a_collection); + init(a_col_name, a_col_schema_name, a_col_type_name, a_col_max_len, a_parent_name,a_hierarchy_level, a_col_position, a_col_type, a_collection); return; end; end; diff --git a/source/expectations/data_values/ut_cursor_column.tps b/source/expectations/data_values/ut_cursor_column.tps index 7782a0d8e..771e20d2c 100644 --- a/source/expectations/data_values/ut_cursor_column.tps +++ b/source/expectations/data_values/ut_cursor_column.tps @@ -11,22 +11,18 @@ create or replace type ut_cursor_column force authid current_user as object column_type varchar2(100), column_type_name varchar2(100), column_schema varchar2(100), - column_prec integer, column_len integer, - column_scale integer, is_sql_diffable number(1, 0), is_collection number(1, 0), member procedure init(self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, - a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, a_col_position integer, a_col_type in varchar2, a_collection integer), constructor function ut_cursor_column( self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, - a_col_type_name varchar2, a_col_prec integer, a_col_scale integer, - a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, a_col_position integer, a_col_type in varchar2, a_collection integer) return self as result ) diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index 1c491ab84..9044e478a 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -13,31 +13,45 @@ create or replace type body ut_cursor_details as return l_diffs; end; - - member function get_anytype_attribute_count(a_anytype anytype) return pls_integer is - l_attribute_typecode pls_integer; - l_schema_name varchar2(32767); + + member procedure get_anytype_members_info(a_anytype anytype, a_attribute_typecode out pls_integer, + a_schema_name out varchar2, a_type_name out varchar2, a_len out pls_integer,a_elements_count out pls_integer) is l_version varchar2(32767); - l_type_name varchar2(32767); - l_attributes pls_integer; l_prec pls_integer; l_scale pls_integer; - l_len pls_integer; l_csid pls_integer; l_csfrm pls_integer; begin - l_attribute_typecode := a_anytype.getinfo(prec => l_prec, + a_attribute_typecode := a_anytype.getinfo(prec => l_prec, scale => l_scale, - len => l_len, + len => a_len, csid => l_csid, csfrm => l_csfrm, - schema_name => l_schema_name, - type_name => l_type_name, + schema_name => a_schema_name, + type_name => a_type_name, version => l_version, - numelems => l_attributes); - return l_attributes; + numelems => a_elements_count); end; + member procedure getattreleminfo(a_anytype anytype,a_pos pls_integer, a_attribute_typecode out pls_integer, + a_type_name out varchar2, a_len out pls_integer) is + l_version varchar2(32767); + l_prec pls_integer; + l_scale pls_integer; + l_csid pls_integer; + l_csfrm pls_integer; + l_attr_elt_type anytype; + begin + a_attribute_typecode := a_anytype.getattreleminfo(pos => a_pos, --First attribute + prec => l_prec, + scale => l_scale, + len => a_len, + csid => l_csid, + csfrm => l_csfrm, + attr_elt_type => l_attr_elt_type, + aname => a_type_name); + end; + member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return anytype is l_anydata anydata; @@ -65,14 +79,12 @@ create or replace type body ut_cursor_details as l_columns_desc dbms_sql.desc_tab3; l_attribute_typecode pls_integer; l_aname varchar2(32767); - l_prec pls_integer; - l_scale pls_integer; l_len pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - l_attr_elt_type anytype; l_anytype anytype; l_is_collection boolean; + l_elements_count pls_integer; + l_schema_name varchar2(100); + l_type_name varchar2(100); begin self.cursor_info := ut_cursor_column_tab(); l_cursor_number := dbms_sql.to_cursor_number(a_cursor); @@ -87,8 +99,6 @@ create or replace type body ut_cursor_details as self.cursor_info(cursor_info.last) := ut_cursor_column( l_columns_desc(cur).col_name, l_columns_desc(cur).col_schema_name, l_columns_desc(cur).col_type_name, - l_columns_desc(cur).col_precision, - l_columns_desc(cur).col_scale, l_columns_desc(cur).col_max_len, null, 1, @@ -96,25 +106,19 @@ create or replace type body ut_cursor_details as ut_compound_data_helper.get_column_type_desc(l_columns_desc(cur).col_type,true), ut_utils.boolean_to_int(l_is_collection) ); + if l_columns_desc(cur).col_type = dbms_sql.user_defined_type and not l_is_collection then l_anytype := get_user_defined_type(l_columns_desc(cur).col_schema_name , l_columns_desc(cur).col_type_name ); - for i in 1 .. get_anytype_attribute_count(l_anytype) loop - l_attribute_typecode := l_anytype.getattreleminfo(pos => i, --First attribute - prec => l_prec, - scale => l_scale, - len => l_len, - csid => l_csid, - csfrm => l_csfrm, - attr_elt_type => l_attr_elt_type, - aname => l_aname); - - l_is_collection := ut_compound_data_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name,l_attribute_typecode); - self.cursor_info.extend; - self.cursor_info(cursor_info.last) := ut_cursor_column( l_aname, + + get_anytype_members_info(l_anytype,l_attribute_typecode,l_schema_name,l_type_name,l_len,l_elements_count); + + for i in 1 .. l_elements_count loop + getattreleminfo(l_anytype,i,l_attribute_typecode,l_aname,l_len); + l_is_collection := ut_compound_data_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name,l_attribute_typecode); + self.cursor_info.extend; + self.cursor_info(cursor_info.last) := ut_cursor_column( l_aname, l_columns_desc(cur).col_schema_name, null, - l_prec, - l_scale, l_len, l_columns_desc(cur).col_name, 2, diff --git a/source/expectations/data_values/ut_cursor_details.tps b/source/expectations/data_values/ut_cursor_details.tps index 2cb77dade..7fd2a478e 100644 --- a/source/expectations/data_values/ut_cursor_details.tps +++ b/source/expectations/data_values/ut_cursor_details.tps @@ -2,7 +2,10 @@ create or replace type ut_cursor_details force authid current_user as object ( cursor_info ut_cursor_column_tab, order member function compare(a_other ut_cursor_details) return integer, - member function get_anytype_attribute_count(a_anytype anytype) return pls_integer, + member procedure get_anytype_members_info(a_anytype anytype, a_attribute_typecode out pls_integer, + a_schema_name out varchar2, a_type_name out varchar2, a_len out pls_integer,a_elements_count out pls_integer), + member procedure getattreleminfo(a_anytype anytype,a_pos pls_integer, a_attribute_typecode out pls_integer, + a_type_name out varchar2, a_len out pls_integer), member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return anytype, constructor function ut_cursor_details(self in out nocopy ut_cursor_details,a_cursor in out nocopy sys_refcursor) return self as result diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index f3fc6ff0f..cc2e92710 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -22,16 +22,55 @@ create or replace type body ut_data_value_refcursor as return; end; - member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) is + member procedure extract_cursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) is c_bulk_rows constant integer := 10000; l_cursor sys_refcursor := a_value; l_ctx number; l_xml xmltype; - l_current_date_format varchar2(4000); - cursor_not_open exception; l_ut_owner varchar2(250) := ut_utils.ut_owner; l_set_id integer := 0; + begin + -- We use DBMS_XMLGEN in order to: + -- 1) be able to process data in bulks (set of rows) + -- 2) be able to influence the ROWSET/ROW tags + -- 3) be able to influence the way NULL values are handled (empty TAG) + -- 4) be able to influence the way TIMESTAMP is formatted. + -- Due to Oracle feature/bug, it is not possible to change the DATE formatting of cursor data + -- AFTER the cursor was opened. + -- The only solution for this is to change NLS settings before opening the cursor. + -- + -- This would work fine if we could use DBMS_XMLGEN.restartQuery. + -- The restartQuery fails however if PLSQL variables of TIMESTAMP/INTERVAL or CLOB/BLOB are used. + ut_expectation_processor.set_xml_nls_params(); + l_ctx := dbms_xmlgen.newContext(l_cursor); + dbms_xmlgen.setNullHandling(l_ctx, dbms_xmlgen.empty_tag); + dbms_xmlgen.setMaxRows(l_ctx, c_bulk_rows); + + loop + l_xml := dbms_xmlgen.getxmltype(l_ctx); + exit when dbms_xmlgen.getNumRowsProcessed(l_ctx) = 0; + + self.elements_count := self.elements_count + dbms_xmlgen.getNumRowsProcessed(l_ctx); + execute immediate + 'insert into ' || l_ut_owner || '.ut_compound_data_tmp(data_id, item_no, item_data) ' || + 'values (:self_guid, :self_row_count, :l_xml)' + using in self.data_id, l_set_id, l_xml; + + l_set_id := l_set_id + c_bulk_rows; + end loop; + + ut_expectation_processor.reset_nls_params(); + dbms_xmlgen.closeContext(l_ctx); + exception + when others then + ut_expectation_processor.reset_nls_params(); + dbms_xmlgen.closeContext(l_ctx); + raise; + end; + member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) is + l_cursor sys_refcursor := a_value; + cursor_not_open exception; begin self.is_data_null := ut_utils.boolean_to_int(a_value is null); self.self_type := $$plsql_unit; @@ -41,46 +80,13 @@ create or replace type body ut_data_value_refcursor as if l_cursor is not null then if l_cursor%isopen then - --Get some more info regarding cursor, including if it containts collection columns and what is their name - + --Get some more info regarding cursor, including if it containts collection columns and what is their name self.elements_count := 0; self.cursor_details := ut_cursor_details(l_cursor); - -- We use DBMS_XMLGEN in order to: - -- 1) be able to process data in bulks (set of rows) - -- 2) be able to influence the ROWSET/ROW tags - -- 3) be able to influence the way NULL values are handled (empty TAG) - -- 4) be able to influence the way TIMESTAMP is formatted. - -- Due to Oracle feature/bug, it is not possible to change the DATE formatting of cursor data - -- AFTER the cursor was opened. - -- The only solution for this is to change NLS settings before opening the cursor. - -- - -- This would work fine if we could use DBMS_XMLGEN.restartQuery. - -- The restartQuery fails however if PLSQL variables of TIMESTAMP/INTERVAL or CLOB/BLOB are used. - - ut_expectation_processor.set_xml_nls_params(); - l_ctx := dbms_xmlgen.newContext(l_cursor); - dbms_xmlgen.setNullHandling(l_ctx, dbms_xmlgen.empty_tag); - dbms_xmlgen.setMaxRows(l_ctx, c_bulk_rows); - - loop - l_xml := dbms_xmlgen.getxmltype(l_ctx); - exit when dbms_xmlgen.getNumRowsProcessed(l_ctx) = 0; - - self.elements_count := self.elements_count + dbms_xmlgen.getNumRowsProcessed(l_ctx); - execute immediate - 'insert into ' || l_ut_owner || '.ut_compound_data_tmp(data_id, item_no, item_data) ' || - 'values (:self_guid, :self_row_count, :l_xml)' - using in self.data_id, l_set_id, l_xml; - - l_set_id := l_set_id + c_bulk_rows; - end loop; - - ut_expectation_processor.reset_nls_params(); + extract_cursor(l_cursor); if l_cursor%isopen then close l_cursor; - end if; - dbms_xmlgen.closeContext(l_ctx); - + end if; elsif not l_cursor%isopen then raise cursor_not_open; end if; @@ -89,11 +95,9 @@ create or replace type body ut_data_value_refcursor as when cursor_not_open then raise_application_error(-20155, 'Cursor is not open'); when others then - ut_expectation_processor.reset_nls_params(); if l_cursor%isopen then close l_cursor; end if; - dbms_xmlgen.closeContext(l_ctx); raise; end; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index f2a748abd..c3270270f 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -31,6 +31,7 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( cursor_details ut_cursor_details, constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) return self as result, + member procedure extract_cursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor), overriding member function to_string return varchar2, member function diff( a_other ut_data_value, a_unordered boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return varchar2, From e082b75c89340b75df3df8e5b33e08f93f851b01 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sat, 1 Dec 2018 19:55:43 +0000 Subject: [PATCH 66/83] Improvements to extraction of cursor details using anydata to allow get into any level of depth ( fix issue with collection object). Simplify a way the cursor filter is done and check for missing column. Full access path is capture as part of cursor describe. Removal of nft test for over 10k rows. --- .../data_values/ut_compound_data_helper.pkb | 105 +++++------ .../data_values/ut_compound_data_helper.pks | 7 +- .../data_values/ut_cursor_column.tpb | 47 ++--- .../data_values/ut_cursor_column.tps | 8 +- .../data_values/ut_cursor_details.tpb | 171 +++++++++++++----- .../data_values/ut_cursor_details.tps | 11 +- .../data_values/ut_data_value_refcursor.tpb | 18 +- .../expectations/test_expectations_cursor.pkb | 45 +---- .../expectations/test_expectations_cursor.pks | 9 - 9 files changed, 224 insertions(+), 197 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 5c2a881d3..5e97cf275 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -375,7 +375,6 @@ create or replace package body ut_compound_data_helper is l_temp_string := ' (a.data_id is null or e.data_id is null) '; end if; ut_utils.append_to_clob(l_compare_sql,l_temp_string); - return l_compare_sql; end; @@ -402,7 +401,6 @@ create or replace package body ut_compound_data_helper is l_results tt_row_diffs; l_sql varchar2(32767); begin - l_sql := q'[with exp as ( select exp_item_data, exp_data_id, item_no rn,rownum col_no, pk_value, s.column_value col, s.column_value.getRootElement() col_name, s.column_value.getclobval() col_val @@ -563,7 +561,7 @@ create or replace package body ut_compound_data_helper is return dbms_crypto.hash(a_data, a_hash_type); end; - function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer :=30) return number is + function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer := 9999999) return number is begin return dbms_utility.get_hash_value(a_string,a_base,a_size); end; @@ -595,69 +593,42 @@ create or replace package body ut_compound_data_helper is return g_diff_count; end; - function get_cursor_vs_list_sql return varchar2 is - l_sql varchar2(32767) := - q'[with - sorted as - (select r_num,regexp_substr(t.column_value, '[^/]+', 1, commas.column_value) as colval,commas.column_value lev, - t.column_value access_path - from (select row_number() over(order by 1) r_num, column_value from ((table(:a_current_list)))) t, - table(cast(multiset - (select level from dual connect by level <= length(regexp_replace(t.column_value,'[^/]+')) + 1) as sys.odcinumberlist)) commas - order by r_num,lev), - hier as - (select r_num,lev,colval column_name,lag(colval, 1) over(partition by r_num order by lev) parent_name , access_path - from sorted), - constructed as ( - select lev,column_name,parent_name,access_path from hier), - t1(column_name, parent_name) AS ( - select column_name,parent_name from table(:a_cursor_info) where parent_name is null - union all - select t2.column_name,t2.parent_name from table(:a_cursor_info) t2, t1 where t2.parent_name = t1.column_name)]'; - begin - return l_sql; - end; - + --Filter out columns from cursor based on include (exists) or exclude (not exists) function filter_out_cols(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list,a_include boolean := true) return ut_cursor_column_tab is - l_sql varchar2(32767) := get_cursor_vs_list_sql; l_result ut_cursor_column_tab := ut_cursor_column_tab(); - begin - l_sql := l_sql || q'[select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name,i.column_len, i.parent_name, - i.hierarchy_level,i.column_position, i.column_type, i.is_collection) - from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name)]'; - if a_include then - l_sql := l_sql || ' join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name)'; - else - l_sql := l_sql ||' left outer join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name) - where c.column_name is null'; - end if; - - execute immediate l_sql bulk collect into l_result - using a_current_list,a_cursor_info,a_cursor_info,a_cursor_info; + l_filter_sql varchar2(32767); + begin + l_filter_sql := + q'[with + coltab as ( + select i.parent_name,i.access_path,i.has_nested_col,i.transformed_name,i.hierarchy_level,i.column_position , + i.xml_valid_name,i.column_name,i.column_type,i.column_type_name ,i.column_schema,i.column_len,i.is_sql_diffable ,i.is_collection + from table(:cursor_info) i), + filter as (select column_value from table(:current_list)) + select ut_cursor_column(i.parent_name,i.access_path,i.has_nested_col,i.transformed_name,i.hierarchy_level,i.column_position , + i.xml_valid_name,i.column_name,i.column_type,i.column_type_name ,i.column_schema,i.column_len,i.is_sql_diffable ,i.is_collection) + from coltab i where ]'||case when a_include then null else ' not ' end + ||q'[exists (select 1 from filter f where regexp_like(i.access_path, '^'||f.column_value||'($|/.*)'))]'; + execute immediate l_filter_sql bulk collect into l_result using a_cursor_info,a_current_list; return l_result; end; - - function compare_cursor_to_columns(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list) - return ut_varchar2_list is - l_sql varchar2(32767) := get_cursor_vs_list_sql; + + function get_missing_filter_columns(a_cursor_info ut_cursor_column_tab, a_column_filter_list ut_varchar2_list) return ut_varchar2_list is l_result ut_varchar2_list := ut_varchar2_list(); - begin - l_sql := l_sql || q'[select c.access_path - from t1 join table(:a_cursor_info) i on ( nvl(t1.parent_name,1) = nvl(i.parent_name,1) and t1.column_name = i.column_name)]'; - l_sql := l_sql ||'right outer join constructed c on ( nvl(t1.parent_name,1) = nvl(c.parent_name,1) and t1.column_name = c.column_name) - where t1.column_name is null'; - - execute immediate l_sql bulk collect into l_result - using a_current_list,a_cursor_info,a_cursor_info,a_cursor_info; - return l_result; + begin + select fl.column_value + bulk collect into l_result + from table(a_column_filter_list) fl + where not exists (select 1 from table(a_cursor_info) c where regexp_like(c.access_path, '^'||fl.column_value||'($|/.*)')); + return l_result; end; - + function get_missing_pk(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab, a_current_list ut_varchar2_list) return tt_missing_pk is - l_actual ut_varchar2_list := coalesce(compare_cursor_to_columns(a_actual,a_current_list),ut_varchar2_list()); - l_expected ut_varchar2_list := coalesce(compare_cursor_to_columns(a_expected,a_current_list),ut_varchar2_list()); + l_actual ut_varchar2_list := coalesce(get_missing_filter_columns(a_actual,a_current_list),ut_varchar2_list()); + l_expected ut_varchar2_list := coalesce(get_missing_filter_columns(a_expected,a_current_list),ut_varchar2_list()); l_missing_pk tt_missing_pk; begin select name,type @@ -735,14 +706,14 @@ create or replace package body ut_compound_data_helper is function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list) return ut_cursor_column_tab is l_result ut_cursor_column_tab; begin - select ut_cursor_column(i.column_name,i.column_schema,i.column_type_name,i.column_len, i.parent_name, - i.hierarchy_level,i.column_position, i.column_type, i.is_collection) + select ut_cursor_column(i.parent_name,i.access_path,i.has_nested_col,i.transformed_name,i.hierarchy_level,i.column_position , + i.xml_valid_name,i.column_name,i.column_type,i.column_type_name ,i.column_schema,i.column_len,i.is_sql_diffable ,i.is_collection) bulk collect into l_result from table(a_cursor_details) i left outer join table(a_incomparable_cols) c on (i.access_path = c.column_value) where c.column_value is null; - + return l_result; end; @@ -759,13 +730,12 @@ create or replace package body ut_compound_data_helper is return xmltype is l_result xmltype; begin - select xmlagg(xmlelement(evalname t.column_name,t.column_type, getxmlchildren(t.column_name,a_cursor_table))) into l_result from table(a_cursor_table) t - where (a_parent_name is not null and parent_name = a_parent_name) - or (a_parent_name is null and parent_name is null) + where (a_parent_name is not null and parent_name = a_parent_name and hierarchy_level > 1 and column_name is not null) + or (a_parent_name is null and parent_name is null and hierarchy_level = 1 and column_name is not null) having count(*) > 0; @@ -805,6 +775,14 @@ create or replace package body ut_compound_data_helper is return false; end; + function is_collection (a_anytype_code in integer) return boolean is + l_type_view varchar2(200) := ut_metadata.get_dba_view('dba_types'); + l_typecode varchar2(100); + begin + return a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection); + end; + + --TODO Look at simplify that option function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is begin return case when a_dbms_sql_desc then g_type_name_map(a_type_code) else g_anytype_name_map(a_type_code) end; @@ -832,7 +810,8 @@ begin g_anytype_name_map(dbms_types.typecode_varray) := 'VARRRAY'; g_anytype_name_map(dbms_types.typecode_table) := 'TABLE'; g_anytype_name_map(dbms_types.typecode_namedcollection) := 'NAMEDCOLLECTION'; - + g_anytype_name_map(dbms_types.typecode_object) := 'OBJECT'; + g_type_name_map( dbms_sql.binary_bouble_type ) := 'BINARY_DOUBLE'; g_type_name_map( dbms_sql.bfile_type ) := 'BFILE'; g_type_name_map( dbms_sql.binary_float_type ) := 'BINARY_FLOAT'; diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index f4ab72856..858c22fe0 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -83,7 +83,7 @@ create or replace package ut_compound_data_helper authid definer is function get_hash(a_data raw, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash; function get_hash(a_data clob, a_hash_type binary_integer := dbms_crypto.hash_sh1) return t_hash; - function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer :=30) return number; + function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer :=9999999) return number; function gen_compare_sql(a_inclusion_type boolean, a_is_negated boolean, a_unordered boolean, a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob; @@ -99,9 +99,6 @@ create or replace package ut_compound_data_helper authid definer is function filter_out_cols(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list,a_include boolean := true) return ut_cursor_column_tab; - function compare_cursor_to_columns(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list) - return ut_varchar2_list; - function get_missing_pk(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab, a_current_list ut_varchar2_list) return tt_missing_pk; @@ -122,6 +119,8 @@ create or replace package ut_compound_data_helper authid definer is function is_collection (a_owner varchar2,a_type_name varchar2, a_anytype_code in integer :=null) return boolean; + function is_collection (a_anytype_code in integer) return boolean; + function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2; end; diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index 85241804f..46f589feb 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -3,46 +3,49 @@ create or replace type body ut_cursor_column as member procedure init(self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, - a_col_position integer, a_col_type varchar2, a_collection integer) is + a_col_position integer, a_col_type varchar2, a_collection integer,a_access_path in varchar2) is begin - self.parent_name := a_parent_name; - self.hierarchy_level := a_hierarchy_level; - self.column_position := a_col_position; - self.column_len := a_col_max_len; - self.column_name := TRIM( BOTH '''' FROM a_col_name); - self.column_type_name := a_col_type_name; - self.access_path := case when self.parent_name is null then self.column_name else self.parent_name||'/'||self.column_name end; - self.xml_valid_name := '"'||self.column_name||'"'; + self.parent_name := a_parent_name; --Name of the parent if its nested + self.hierarchy_level := a_hierarchy_level; --Hierarchy level + self.column_position := a_col_position; --Position of the column in cursor/ type + self.column_len := a_col_max_len; --length of column + self.column_name := TRIM( BOTH '''' FROM a_col_name); --name of the column + self.column_type_name := a_col_type_name; --type name e.g. test_dummy_object or varchar2 + self.access_path := case when a_access_path is null then + self.column_name + else + a_access_path||'/'||self.column_name + end; --Access path used for incldue exclude eg/ TEST_DUMMY_OBJECT/VARCHAR2 + self.xml_valid_name := '"'||self.column_name||'"'; --User friendly column name self.transformed_name := case when self.parent_name is null then self.xml_valid_name else '"'||ut_compound_data_helper.get_fixed_size_hash(self.parent_name||self.column_name)||'"' - end; - self.column_type := a_col_type; - self.column_schema := a_col_schema_name; + end; --when is nestd we need to hash name to make sure we dont exceed 30 char + self.column_type := a_col_type; --column type e.g. user_defined , varchar2 + self.column_schema := a_col_schema_name; -- schema name self.is_sql_diffable := case when lower(self.column_type) = 'user_defined_type' then 0 else ut_utils.boolean_to_int(ut_compound_data_helper.is_sql_compare_allowed(self.column_type)) - end; - --TODO : Part of the constructor same as has nested ?? + end; --can we directly compare or do we need to hash value self.is_collection := a_collection; --TODO : fix that as is nasty hardcode self.has_nested_col := case when lower(self.column_type) = 'user_defined_type' and self.is_collection = 0 then 1 else 0 end; end; - - --TODO : Scenarios : - --namedcollection xmltype getclobhash - --collection xml type get clob hash - -- user defined type - + constructor function ut_cursor_column( self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, - a_col_position integer, a_col_type in varchar2, a_collection integer) return self as result is + a_col_position integer, a_col_type in varchar2, a_collection integer,a_access_path in varchar2) return self as result is begin - init(a_col_name, a_col_schema_name, a_col_type_name, a_col_max_len, a_parent_name,a_hierarchy_level, a_col_position, a_col_type, a_collection); + init(a_col_name, a_col_schema_name, a_col_type_name, a_col_max_len, a_parent_name,a_hierarchy_level, a_col_position, a_col_type, a_collection,a_access_path); return; end; + + constructor function ut_cursor_column( self in out nocopy ut_cursor_column) return self as result is + begin + return; + end; end; / diff --git a/source/expectations/data_values/ut_cursor_column.tps b/source/expectations/data_values/ut_cursor_column.tps index 771e20d2c..6a4929d2d 100644 --- a/source/expectations/data_values/ut_cursor_column.tps +++ b/source/expectations/data_values/ut_cursor_column.tps @@ -18,12 +18,14 @@ create or replace type ut_cursor_column force authid current_user as object member procedure init(self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, - a_col_position integer, a_col_type in varchar2, a_collection integer), + a_col_position integer, a_col_type in varchar2, a_collection integer,a_access_path in varchar2), constructor function ut_cursor_column( self in out nocopy ut_cursor_column, a_col_name varchar2, a_col_schema_name varchar2, a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, - a_col_position integer, a_col_type in varchar2, a_collection integer) - return self as result + a_col_position integer, a_col_type in varchar2, a_collection integer,a_access_path in varchar2) + return self as result, + + constructor function ut_cursor_column( self in out nocopy ut_cursor_column) return self as result ) / diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index 9044e478a..eba4bc884 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -2,15 +2,13 @@ create or replace type body ut_cursor_details as order member function compare(a_other ut_cursor_details) return integer is l_diffs integer; - begin - + begin select count(1) into l_diffs from table(self.cursor_info) a full outer join table(a_other.cursor_info) e on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and REPLACE(a.column_type,'VARCHAR2','CHAR') = REPLACE(e.column_type,'VARCHAR2','CHAR') and a.column_position = e.column_position ) - where a.column_name is null or e.column_name is null; - + where a.column_name is null or e.column_name is null; return l_diffs; end; @@ -34,7 +32,7 @@ create or replace type body ut_cursor_details as end; member procedure getattreleminfo(a_anytype anytype,a_pos pls_integer, a_attribute_typecode out pls_integer, - a_type_name out varchar2, a_len out pls_integer) is + a_type_name out varchar2, a_len out pls_integer, a_attr_elt_type out anytype) is l_version varchar2(32767); l_prec pls_integer; l_scale pls_integer; @@ -70,29 +68,133 @@ create or replace type body ut_cursor_details as return l_anytype; end; + + member function get_user_defined_type(a_data anydata) return anytype is + l_anytype anytype; + l_typecode pls_integer; + begin + l_typecode:=a_data.gettype(l_anytype); + return l_anytype; + end; + + member function get_anydata_from_compound_data(a_owner varchar2, a_type_name varchar2,a_type varchar2) return anydata is + l_anydata anydata; + begin + execute immediate ' + declare + l_obj '||a_owner||'.'||a_type_name||'; + begin + :anydata := sys.anydata.convert'||a_type||'(l_obj); + end;' + using out l_anydata; + return l_anydata; + end; + + member function get_anytype_of_coll_element(a_collection_owner in varchar2, a_collection_name in varchar2) + return anytype is + l_anytype anytype; + l_anydata anydata; + l_owner varchar2(100); + l_type_name varchar2(100); + begin + l_anydata := get_anydata_from_compound_data(a_collection_owner,a_collection_name,'collection'); + execute immediate' + declare + l_data '||a_collection_owner||'.'||a_collection_name||'; + l_value anydata := :a_value; + l_status integer; + l_loc_query sys_refcursor; + l_cursor_number number; + l_columns_count pls_integer; + l_columns_desc dbms_sql.desc_tab3; + begin + l_status := l_value.getcollection(l_data); + l_data := '||a_collection_owner||'.'||a_collection_name||q'[(); + l_data.extend; + open l_loc_query for select l_data(1) from dual; + l_cursor_number := dbms_sql.to_cursor_number(l_loc_query); + dbms_sql.describe_columns3(l_cursor_number, + l_columns_count, + l_columns_desc); + :owner := l_columns_desc(1).col_schema_name; + :type_name := l_columns_desc(1).col_type_name; + dbms_sql.close_cursor(l_cursor_number); + end;]' using l_anydata, out l_owner,out l_type_name; + l_anytype := get_user_defined_type(l_owner, l_type_name); + return l_anytype; + end; + + member procedure desc_compound_data(self in out nocopy ut_cursor_details,a_compound_data anytype, + a_parent_name in varchar2,a_level in integer, a_access_path in varchar2) is + l_idx pls_integer := 1; + l_elements_count pls_integer; + l_attribute_typecode pls_integer; + l_aname varchar2(32767); + l_len pls_integer; + l_is_collection boolean; + l_schema_name varchar2(100); + l_hierarchy_level integer := a_level; + l_object_type varchar2(10); + l_anydata anydata; + l_attr_elt_type anytype; + begin + get_anytype_members_info(a_compound_data,l_attribute_typecode,l_schema_name,l_aname,l_len,l_elements_count); + while l_idx <= nvl(l_elements_count,1) loop + if l_elements_count is not null then + getattreleminfo(a_compound_data,l_idx,l_attribute_typecode,l_aname,l_len,l_attr_elt_type); + elsif l_attribute_typecode in (dbms_types.typecode_table, dbms_types.typecode_varray, dbms_types.typecode_namedcollection) then + l_attr_elt_type := get_anytype_of_coll_element(l_schema_name, l_aname); + end if; + + l_is_collection := ut_compound_data_helper.is_collection(l_attribute_typecode); + self.cursor_info.extend; + self.cursor_info(cursor_info.last) := ut_cursor_column( l_aname, + l_schema_name, + null, + l_len, + a_parent_name, + l_hierarchy_level, + l_idx, + ut_compound_data_helper.get_column_type_desc(l_attribute_typecode,false), + ut_utils.boolean_to_int(l_is_collection), + a_access_path + ); + if l_attr_elt_type is not null then + desc_compound_data(l_attr_elt_type,l_aname,l_hierarchy_level+1,a_access_path||'/'||l_aname); + end if; + l_idx := l_idx + 1; + end loop; + end; + + constructor function ut_cursor_details(self in out nocopy ut_cursor_details) return self as result is + begin + self.cursor_info := ut_cursor_column_tab(); + return; + end; - constructor function ut_cursor_details(self in out nocopy ut_cursor_details, - a_cursor in out nocopy sys_refcursor) + constructor function ut_cursor_details(self in out nocopy ut_cursor_details + ,a_cursor_number in number) return self as result is l_cursor_number integer; l_columns_count pls_integer; l_columns_desc dbms_sql.desc_tab3; - l_attribute_typecode pls_integer; - l_aname varchar2(32767); - l_len pls_integer; - l_anytype anytype; + l_anydata anydata; l_is_collection boolean; - l_elements_count pls_integer; - l_schema_name varchar2(100); - l_type_name varchar2(100); + l_object_type varchar2(10); + l_hierarchy_level integer := 1; + l_anytype anytype; begin self.cursor_info := ut_cursor_column_tab(); - l_cursor_number := dbms_sql.to_cursor_number(a_cursor); - dbms_sql.describe_columns3(l_cursor_number, + dbms_sql.describe_columns3(a_cursor_number, l_columns_count, l_columns_desc); - a_cursor := dbms_sql.to_refcursor(l_cursor_number); - + + /** + * Due to a bug with object being part of cursor in anydata scanario + * oracle fails to revert number to cursor. We ar using dbms_sql.close cursor to close it + * to avoid leaving open cursors behind. + * a_cursor := dbms_sql.to_refcursor(l_cursor_number); + **/ for cur in 1 .. l_columns_count loop l_is_collection := ut_compound_data_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name); self.cursor_info.extend; @@ -101,36 +203,23 @@ create or replace type body ut_cursor_details as l_columns_desc(cur).col_type_name, l_columns_desc(cur).col_max_len, null, - 1, + l_hierarchy_level, cur, ut_compound_data_helper.get_column_type_desc(l_columns_desc(cur).col_type,true), - ut_utils.boolean_to_int(l_is_collection) + ut_utils.boolean_to_int(l_is_collection), + null ); - if l_columns_desc(cur).col_type = dbms_sql.user_defined_type and not l_is_collection then - l_anytype := get_user_defined_type(l_columns_desc(cur).col_schema_name , l_columns_desc(cur).col_type_name ); - - get_anytype_members_info(l_anytype,l_attribute_typecode,l_schema_name,l_type_name,l_len,l_elements_count); - - for i in 1 .. l_elements_count loop - getattreleminfo(l_anytype,i,l_attribute_typecode,l_aname,l_len); - l_is_collection := ut_compound_data_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name,l_attribute_typecode); - self.cursor_info.extend; - self.cursor_info(cursor_info.last) := ut_cursor_column( l_aname, - l_columns_desc(cur).col_schema_name, - null, - l_len, - l_columns_desc(cur).col_name, - 2, - i, - ut_compound_data_helper.get_column_type_desc(l_attribute_typecode,false), - ut_utils.boolean_to_int(l_is_collection) - ); - end loop; + if l_columns_desc(cur).col_type = dbms_sql.user_defined_type or l_is_collection then + l_object_type := case when l_is_collection then 'collection' else 'object' end; + l_anydata := get_anydata_from_compound_data(l_columns_desc(cur).col_schema_name, l_columns_desc(cur).col_type_name, + l_object_type); + l_anytype := get_user_defined_type(l_anydata); + desc_compound_data(l_anytype,l_columns_desc(cur).col_name,l_hierarchy_level+1,l_columns_desc(cur).col_name); end if; end loop; - return; end; + end; / diff --git a/source/expectations/data_values/ut_cursor_details.tps b/source/expectations/data_values/ut_cursor_details.tps index 7fd2a478e..b38fec0fb 100644 --- a/source/expectations/data_values/ut_cursor_details.tps +++ b/source/expectations/data_values/ut_cursor_details.tps @@ -5,9 +5,16 @@ create or replace type ut_cursor_details force authid current_user as object member procedure get_anytype_members_info(a_anytype anytype, a_attribute_typecode out pls_integer, a_schema_name out varchar2, a_type_name out varchar2, a_len out pls_integer,a_elements_count out pls_integer), member procedure getattreleminfo(a_anytype anytype,a_pos pls_integer, a_attribute_typecode out pls_integer, - a_type_name out varchar2, a_len out pls_integer), + a_type_name out varchar2, a_len out pls_integer,a_attr_elt_type out anytype), + member function get_anytype_of_coll_element(a_collection_owner in varchar2, a_collection_name in varchar2) + return anytype, + member procedure desc_compound_data(self in out nocopy ut_cursor_details,a_compound_data anytype, + a_parent_name in varchar2,a_level in integer,a_access_path in varchar2), + member function get_anydata_from_compound_data(a_owner varchar2, a_type_name varchar2,a_type varchar2) return anydata, member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return anytype, - constructor function ut_cursor_details(self in out nocopy ut_cursor_details,a_cursor in out nocopy sys_refcursor) + member function get_user_defined_type(a_data anydata) return anytype, + constructor function ut_cursor_details(self in out nocopy ut_cursor_details) return self as result, + constructor function ut_cursor_details(self in out nocopy ut_cursor_details,a_cursor_number in number) return self as result ) / diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index cc2e92710..5738638ec 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -41,11 +41,11 @@ create or replace type body ut_data_value_refcursor as -- -- This would work fine if we could use DBMS_XMLGEN.restartQuery. -- The restartQuery fails however if PLSQL variables of TIMESTAMP/INTERVAL or CLOB/BLOB are used. + ut_expectation_processor.set_xml_nls_params(); l_ctx := dbms_xmlgen.newContext(l_cursor); dbms_xmlgen.setNullHandling(l_ctx, dbms_xmlgen.empty_tag); - dbms_xmlgen.setMaxRows(l_ctx, c_bulk_rows); - + dbms_xmlgen.setMaxRows(l_ctx, c_bulk_rows); loop l_xml := dbms_xmlgen.getxmltype(l_ctx); exit when dbms_xmlgen.getNumRowsProcessed(l_ctx) = 0; @@ -54,11 +54,9 @@ create or replace type body ut_data_value_refcursor as execute immediate 'insert into ' || l_ut_owner || '.ut_compound_data_tmp(data_id, item_no, item_data) ' || 'values (:self_guid, :self_row_count, :l_xml)' - using in self.data_id, l_set_id, l_xml; - - l_set_id := l_set_id + c_bulk_rows; + using in self.data_id, l_set_id, l_xml; + l_set_id := l_set_id + c_bulk_rows; end loop; - ut_expectation_processor.reset_nls_params(); dbms_xmlgen.closeContext(l_ctx); exception @@ -71,6 +69,7 @@ create or replace type body ut_data_value_refcursor as member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) is l_cursor sys_refcursor := a_value; cursor_not_open exception; + l_cursor_number number; begin self.is_data_null := ut_utils.boolean_to_int(a_value is null); self.self_type := $$plsql_unit; @@ -82,11 +81,10 @@ create or replace type body ut_data_value_refcursor as if l_cursor%isopen then --Get some more info regarding cursor, including if it containts collection columns and what is their name self.elements_count := 0; - self.cursor_details := ut_cursor_details(l_cursor); extract_cursor(l_cursor); - if l_cursor%isopen then - close l_cursor; - end if; + l_cursor_number := dbms_sql.to_cursor_number(l_cursor); + self.cursor_details := ut_cursor_details(l_cursor_number); + dbms_sql.close_cursor(l_cursor_number); elsif not l_cursor%isopen then raise cursor_not_open; end if; diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 54dafd37a..ca6faad5b 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -894,21 +894,6 @@ Rows: [ 4 differences ] ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; - procedure compares_over_10000_rows - as - l_actual sys_refcursor; - l_expected sys_refcursor; - begin - --Arrange - open l_actual for select object_name from all_objects where rownum <=11000 order by object_id; - open l_expected for select object_name from all_objects where rownum <=11000 order by object_id; - --Act - ut3.ut.expect(l_actual).to_equal(l_expected); - - --Assert - ut.expect(expectations.failed_expectations_data()).to_be_empty(); - end; - function get_cursor return sys_refcursor is l_cursor sys_refcursor; begin @@ -1230,21 +1215,8 @@ Diff:% --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; - - procedure cursor_joinby_compare_10000 is - l_actual SYS_REFCURSOR; - l_expected SYS_REFCURSOR; - begin - --Arrange - open l_actual for select level object_id, level || '_TEST' object_name from dual connect by level <=11000; - open l_expected for select level object_id, level || '_TEST' object_name from dual connect by level <=11000; - --Act - ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OBJECT_ID'); - --Assert - ut.expect(expectations.failed_expectations_data()).to_be_empty(); - end; - - procedure cursor_unorder_compare_1000 is + + procedure cursor_unorder_compare_1000 is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; begin @@ -1256,19 +1228,6 @@ Diff:% --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; - - procedure cursor_unorder_compare_10000 is - l_actual SYS_REFCURSOR; - l_expected SYS_REFCURSOR; - begin - --Arrange - open l_actual for select level object_id, level || '_TEST' object_name from dual connect by level <=11000; - open l_expected for select level object_id, level || '_TEST' object_name from dual connect by level <=11000; - --Act - ut3.ut.expect(l_actual).to_equal(l_expected).unordered; - --Assert - ut.expect(expectations.failed_expectations_data()).to_be_empty(); - end; procedure cursor_joinby_compare_fail is l_actual SYS_REFCURSOR; diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index ce02623dd..ae52d741c 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -166,9 +166,6 @@ create or replace package test_expectations_cursor is --%test(Compares cursors with more than 1000 rows) procedure compares_over_1000_rows; - --%test(Compares cursors with more than 10000 rows) - procedure compares_over_10000_rows; - --%test(Adds a warning when using depreciated syntax to_equal( a_expected sys_refcursor, a_exclude varchar2 )) procedure deprec_to_equal_excl_varch; @@ -225,15 +222,9 @@ create or replace package test_expectations_cursor is --%test( Compare cursors join by single key more than 1000 rows) procedure cursor_joinby_compare_1000; - - --%test( Compare cursors join by single key more than 10000 rows) - procedure cursor_joinby_compare_10000; --%test( Compare cursors unorder more than 1000 rows) procedure cursor_unorder_compare_1000; - - --%test( Compare cursors unorder more than 10000 rows) - procedure cursor_unorder_compare_10000; --%test( Compare two column cursors join by and fail to match ) procedure cursor_joinby_compare_fail; From 815deacebef62195076690588a20ac4145e64219 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 2 Dec 2018 13:46:20 +0000 Subject: [PATCH 67/83] Updates to documentation Cleanup of te code --- docs/about/authors.md | 4 ++-- docs/userguide/advanced_data_comparison.md | 20 ++++++++---------- .../data_values/ut_compound_data_helper.pkb | 21 ------------------- .../data_values/ut_compound_data_helper.pks | 4 ---- .../data_values/ut_compound_data_value.tpb | 11 +--------- source/expectations/matchers/ut_include.tpb | 14 ++++--------- .../expectations/test_expectations_cursor.pkb | 11 +++++----- 7 files changed, 22 insertions(+), 63 deletions(-) diff --git a/docs/about/authors.md b/docs/about/authors.md index 55f85642d..76bb24e5f 100644 --- a/docs/about/authors.md +++ b/docs/about/authors.md @@ -7,11 +7,11 @@ | ---------------- | -------------- | David Pyke | [Shoelace](https://github.com/Shoelace) | Jacek Gebal | [jgebal](https://github.com/jgebal) +| Lukasz Wasylow | [lwasylow](https://github.com/lwasylow/) | Pavel Kaplya | [Pazus](https://github.com/Pazus) | Robert Love | [rlove](https://github.com/rlove) -| Vinicius Avellar | [viniciusam](https://github.com/viniciusam/) | Samuel Nitsche | [pesse](https://github.com/pesse/) -| Lukasz Wasylow | [lwasylow](https://github.com/lwasylow/) +| Vinicius Avellar | [viniciusam](https://github.com/viniciusam/) diff --git a/docs/userguide/advanced_data_comparison.md b/docs/userguide/advanced_data_comparison.md index 2b27bf54e..c5e751526 100644 --- a/docs/userguide/advanced_data_comparison.md +++ b/docs/userguide/advanced_data_comparison.md @@ -35,15 +35,12 @@ Each item in the comma separated list can be: - a column name of cursor to be compared - an attribute name of object type to be compared - an attribute name of object type within a table of objects to be compared -- an [XPath](http://zvon.org/xxl/XPathTutorial/Output/example1.html) expression representing column/attribute - Include and exclude option will not support implicit colum names that starts with single quota, or in fact any other special characters e.g. <, >, & Each element in `ut_varchar2_list` nested table can be an item or a comma separated list of items. When specifying column/attribute names, keep in mind that the names are **case sensitive**. -**XPath expressions with comma are not supported.** - ## Excluding elements from data comparison Consider the following examples @@ -286,30 +283,31 @@ Diff: ***Please note that .join_by option will take longer to process due to need of parsing via primary keys.*** -## Defining item as XPath -When using XPath expression, keep in mind the following: +## Defining item lists in option +XPath expressions are deprecated. They are currently still supported but in future versions they can be removed completely. Please use a current standard of defining items filter. + +When using item list expression, keep in mind the following: -- cursor columns are nested under `` element - object type attributes are nested under `` element - nested table and varray items type attributes are nested under `` elements -Example of a valid XPath parameter to include columns: `RN`, `A_Column`, `SOME_COL` in data comparison. +Example of a valid parameter to include columns: `RN`, `A_Column`, `SOME_COL` in data comparison. ```sql -procedure include_col_as_xpath_eq is +procedure include_col_list_eq is l_actual sys_refcursor; l_expected sys_refcursor; begin open l_expected for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL from dual a connect by level < 4; open l_actual for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL, a.* from all_objects a where rownum < 4; - ut.expect( l_actual ).to_equal( l_expected ).include( '/ROW/RN|/ROW/A_Column|/ROW/SOME_COL' ); + ut.expect( l_actual ).to_equal( l_expected ).include( 'RN,A_Column,SOME_COL' ); end; -procedure include_col_as_xpath_cn is +procedure include_col_list_eq is l_actual sys_refcursor; l_expected sys_refcursor; begin open l_expected for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL from dual a connect by level < 4; open l_actual for select rownum as rn, 'a' as "A_Column", 'x' SOME_COL, a.* from all_objects a where rownum < 6; - ut.expect( l_actual ).to_include( l_expected ).include( '/ROW/RN|/ROW/A_Column|/ROW/SOME_COL' ); + ut.expect( l_actual ).to_include( l_expected ).include( 'RN,A_Column,SOME_COL' ); end; ``` diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 5e97cf275..88feb394f 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -640,18 +640,6 @@ create or replace package body ut_compound_data_helper is order by type desc,name; return l_missing_pk; end; - - function validate_attributes(a_cursor_info ut_cursor_column_tab,a_filter_list ut_varchar2_list) - return ut_varchar2_list is - l_result ut_varchar2_list := ut_varchar2_list(); - begin - select col_name bulk collect into l_result - from (select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_name - from table(a_filter_list)) flr left outer join table(a_cursor_info) cur - on (flr.col_name = cur.access_path) where cur.access_path is null; - - return l_result; - end; function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_cursor_column_tab is @@ -716,15 +704,6 @@ create or replace package body ut_compound_data_helper is return l_result; end; - - function generate_missing_cols_warn_msg(a_missing_columns ut_varchar2_list,a_attribute in varchar2) return varchar2 is - l_warn_msg varchar2(32767) := 'For specified option :'||a_attribute||' following columns not exists in cursor:'||chr(10); - begin - for i in 1..a_missing_columns.count loop - l_warn_msg := l_warn_msg||a_missing_columns(i)||chr(10); - end loop; - return l_warn_msg; - end; function getxmlchildren(a_parent_name varchar2,a_cursor_table ut_cursor_column_tab) return xmltype is diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 858c22fe0..80bae9c36 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -102,8 +102,6 @@ create or replace package ut_compound_data_helper authid definer is function get_missing_pk(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab, a_current_list ut_varchar2_list) return tt_missing_pk; - function validate_attributes(a_cursor_info ut_cursor_column_tab, a_filter_list ut_varchar2_list) return ut_varchar2_list; - function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_cursor_column_tab; @@ -111,8 +109,6 @@ create or replace package ut_compound_data_helper authid definer is function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list) return ut_cursor_column_tab; - function generate_missing_cols_warn_msg(a_missing_columns ut_varchar2_list,a_attribute in varchar2) return varchar2; - function getxmlchildren(a_parent_name varchar2,a_cursor_table ut_cursor_column_tab) return xmltype; function is_sql_compare_allowed(a_type_name varchar2) return boolean; diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index a06ac1d14..2d1b52914 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -96,16 +96,7 @@ create or replace type body ut_compound_data_value as function get_diff_message (a_row_diff ut_compound_data_helper.t_row_diffs,a_is_unordered boolean) return varchar2 is begin - - if a_is_unordered then - if a_row_diff.pk_value is not null then - return ' PK '||a_row_diff.pk_value||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - else - return rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - end if; - else - return ' Row No. '||a_row_diff.rn||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; - end if; + return ' Row No. '||a_row_diff.rn||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; end; begin diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index 07ba65f5d..c34f19a60 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -74,16 +74,10 @@ create or replace type body ut_include as l_actual ut_data_value; begin if self.expected.data_type = a_actual.data_type and self.expected.is_diffable then - if self.expected is of (ut_data_value_refcursor) then - l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); - l_result := - 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() - || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(self.exclude_list, self.include_list).diff(l_actual, true, self.get_join_by_list()); - else - l_result := - 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() - || chr(10) || 'Diff:' || expected.diff(a_actual, self.get_exclude_xpath(), self.get_include_xpath(), self.get_join_by_xpath(), true); - end if; + l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); + l_result := + 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() + || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(self.exclude_list, self.include_list).diff(l_actual, true, self.get_join_by_list()); else l_result := (self as ut_matcher).failure_message(a_actual) || ': '|| self.expected.to_string_report(); end if; diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index ca6faad5b..5e786ff21 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -1755,15 +1755,16 @@ Diff:% from dual connect by level <=2; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).join_by('NESTED_TABLE/UT_KEY_VALUE_PAIR'); + ut3.ut.expect(l_actual).to_equal(l_expected).join_by('NESTED_TABLE/UT_KEY_VALUE_PAIRS'); --Assert l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ] %Diff: -%Unable to join sets: -%Join key NESTED_TABLE/UT_KEY_VALUE_PAIR does not exists in expected% -%Join key NESTED_TABLE/UT_KEY_VALUE_PAIR does not exists in actual% -%Please make sure that your join clause is not refferring to collection element%]'; +%Rows: [ 4 differences ] +%Extra: 21Something 12Something 2 +%Extra: 11Something 12Something 2 +%Missing: 11Somethings 12Somethings 2 +%Missing: 21Somethings 12Somethings 2%]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); From cf0c592ea9655f0ed1ee04a9eb63eea19a1db9da Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 2 Dec 2018 14:11:54 +0000 Subject: [PATCH 68/83] Sorting out some duplicate code. --- .../data_values/ut_compound_data_helper.pkb | 73 ++++++++----------- 1 file changed, 30 insertions(+), 43 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 88feb394f..895e63c2f 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -256,12 +256,37 @@ create or replace package body ut_compound_data_helper is end if; end; + procedure get_act_and_exp_set(a_current_stmt in out nocopy clob, a_partition_stmt clob, a_select_stmt clob, + a_xmltable_stmt clob, a_unordered boolean,a_type varchar2) is + l_temp_string varchar2(32767); + l_ut_owner varchar2(250) := ut_utils.ut_owner; + begin + ut_utils.append_to_clob(a_current_stmt, a_partition_stmt); + + l_temp_string := 'from (select ucd.item_data '; + ut_utils.append_to_clob(a_current_stmt,l_temp_string); + ut_utils.append_to_clob(a_current_stmt, a_select_stmt); + + l_temp_string := ',x.data_id, ' + || case when not a_unordered then 'position + x.item_no ' else 'rownum ' end + ||'item_no from ' || l_ut_owner || '.ut_compound_data_tmp x,' + ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' ; + ut_utils.append_to_clob(a_current_stmt,l_temp_string); + + ut_utils.append_to_clob(a_current_stmt,a_xmltable_stmt); + ut_utils.append_to_clob(a_current_stmt,case when a_xmltable_stmt is null then '' else ',' end||q'[ item_data xmltype PATH '*']'); + if not a_unordered then + ut_utils.append_to_clob(a_current_stmt,', POSITION for ordinality '); + end if; + ut_utils.append_to_clob(a_current_stmt,' ) ucd where data_id = :'||a_type||'_guid ) ucd ) '); + end; + + function gen_compare_sql(a_inclusion_type boolean, a_is_negated boolean,a_unordered boolean, a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob is l_compare_sql clob; l_temp_string varchar2(32767); - l_ut_owner varchar2(250) := ut_utils.ut_owner; l_xmltable_stmt clob; l_where_stmt clob; l_select_stmt clob; @@ -289,50 +314,12 @@ create or replace package body ut_compound_data_helper is l_temp_string := 'with exp as ( select ucd.* '; ut_utils.append_to_clob(l_compare_sql, l_temp_string); - ut_utils.append_to_clob(l_compare_sql,l_partition_stmt); + get_act_and_exp_set(l_compare_sql, l_partition_stmt,l_select_stmt, l_xmltable_stmt, a_unordered,'exp'); - l_temp_string := 'from (select ucd.item_data '; - ut_utils.append_to_clob(l_compare_sql, l_temp_string); - ut_utils.append_to_clob(l_compare_sql, l_select_stmt); - - l_temp_string := ',x.data_id ,' - || case when not a_unordered then 'position + x.item_no ' else 'rownum ' end - ||'item_no from '|| l_ut_owner || '.ut_compound_data_tmp x, ' - ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]'; - ut_utils.append_to_clob(l_compare_sql, l_temp_string); - - ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt); - ut_utils.append_to_clob(l_compare_sql,case when l_xmltable_stmt is null then '' else ',' end||q'[ item_data xmltype PATH '*']'); - - if not a_unordered then - ut_utils.append_to_clob(l_compare_sql,', POSITION for ordinality '); - end if; - - l_temp_string := q'[) ucd where data_id = :self_guid ) ucd ) ,]'; - ut_utils.append_to_clob(l_compare_sql,l_temp_string); - - l_temp_string :='act as ( select ucd.* '; + + l_temp_string :=',act as ( select ucd.* '; ut_utils.append_to_clob(l_compare_sql, l_temp_string); - ut_utils.append_to_clob(l_compare_sql, l_partition_stmt); - - l_temp_string := 'from (select ucd.item_data '; - ut_utils.append_to_clob(l_compare_sql,l_temp_string); - ut_utils.append_to_clob(l_compare_sql, l_select_stmt); - - l_temp_string := ',x.data_id, ' - || case when not a_unordered then 'position + x.item_no ' else 'rownum ' end - ||'item_no from ' || l_ut_owner || '.ut_compound_data_tmp x,' - ||q'[xmltable('/ROWSET/ROW' passing x.item_data columns ]' ; - ut_utils.append_to_clob(l_compare_sql,l_temp_string); - - ut_utils.append_to_clob(l_compare_sql,l_xmltable_stmt); - ut_utils.append_to_clob(l_compare_sql,case when l_xmltable_stmt is null then '' else ',' end||q'[ item_data xmltype PATH '*']'); - - if not a_unordered then - ut_utils.append_to_clob(l_compare_sql,', POSITION for ordinality '); - end if; - - ut_utils.append_to_clob(l_compare_sql,q'[ ) ucd where data_id = :other_guid ) ucd ) ]'); + get_act_and_exp_set(l_compare_sql, l_partition_stmt,l_select_stmt, l_xmltable_stmt, a_unordered,'act'); l_temp_string := ' select a.item_data as act_item_data, a.data_id act_data_id,' ||'e.item_data as exp_item_data, e.data_id exp_data_id, '|| From c156852786c1bc209ddf34a7338b74139e41dc91 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 2 Dec 2018 14:34:43 +0000 Subject: [PATCH 69/83] Cleanup of code --- source/expectations/data_values/ut_compound_data_helper.pkb | 4 ---- source/expectations/data_values/ut_compound_data_value.tpb | 2 -- source/expectations/data_values/ut_cursor_column.tpb | 1 - source/expectations/data_values/ut_data_value_refcursor.tpb | 1 - source/expectations/matchers/ut_equal.tpb | 4 ---- source/expectations/matchers/ut_include.tpb | 1 - 6 files changed, 13 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 895e63c2f..49414cd11 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -134,7 +134,6 @@ create or replace package body ut_compound_data_helper is l_sql_stmt := l_sql_stmt ||' a.'||a_col_name||q'[ = ]'||' e.'||a_col_name; elsif a_data_info.parent_name = l_pk_tab(l_index)then --When then table is nested and join is on whole table - --TODO : Can this be done smarter ? l_sql_stmt := case when a_join_by_stmt is null then null else ' and ' end; l_sql_stmt := l_sql_stmt ||' a.'||a_col_name||q'[ = ]'||' e.'||a_col_name; end if; @@ -168,7 +167,6 @@ create or replace package body ut_compound_data_helper is l_sql_stmt := l_sql_stmt ||l_alias||a_col_name; elsif a_data_info.parent_name = l_pk_tab(l_index)then --When then table is nested and join is on whole table - --TODO : Can this be done smarter ? l_sql_stmt := case when a_partition_stmt is null then null else ',' end; l_sql_stmt := l_sql_stmt ||l_alias||a_col_name; end if; @@ -202,7 +200,6 @@ create or replace package body ut_compound_data_helper is begin if a_data_info.is_sql_diffable = 0 then l_col_type := 'XMLTYPE'; - --TODO : Is it right to use timestamp ? elsif a_data_info.is_sql_diffable = 1 and a_data_info.column_type = 'DATE' then l_col_type := 'TIMESTAMP'; elsif a_data_info.is_sql_diffable = 1 and a_data_info.column_type in ('TIMESTAMP','TIMESTAMP WITH TIME ZONE') then @@ -748,7 +745,6 @@ create or replace package body ut_compound_data_helper is return a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection); end; - --TODO Look at simplify that option function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is begin return case when a_dbms_sql_desc then g_type_name_map(a_type_code) else g_anytype_name_map(a_type_code) end; diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 2d1b52914..81e9d8c39 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -111,7 +111,6 @@ create or replace type body ut_compound_data_value as l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_actual.data_id); -- First tell how many rows are different l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; - --TODO : Change message when the types not matching if l_diff_row_count > 0 then l_row_diffs := ut_compound_data_helper.get_rows_diff( self.data_id, l_actual.data_id, l_diff_id, c_max_rows, a_exclude_xpath, @@ -206,7 +205,6 @@ create or replace type body ut_compound_data_value as l_sql_rowcount integer :=0; begin - --TODO : Bring diffs row into same place for ref data cursor especially (how we going to do that so we dont break anyval etc) l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index 46f589feb..52be9a3d4 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -30,7 +30,6 @@ create or replace type body ut_cursor_column as ut_utils.boolean_to_int(ut_compound_data_helper.is_sql_compare_allowed(self.column_type)) end; --can we directly compare or do we need to hash value self.is_collection := a_collection; - --TODO : fix that as is nasty hardcode self.has_nested_col := case when lower(self.column_type) = 'user_defined_type' and self.is_collection = 0 then 1 else 0 end; end; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 5738638ec..b2314cf48 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -235,7 +235,6 @@ create or replace type body ut_data_value_refcursor as l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; l_results := ut_utils.t_clob_tab(); if l_diff_row_count > 0 then - --TODO : since columns can differ we need to pass both list or get common denominator l_row_diffs := ut_compound_data_helper.get_rows_diff_by_sql( l_exp_cols,l_act_cols, self.data_id, l_actual.data_id, l_diff_id,a_join_by_list , a_unordered); l_message := chr(10) diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index d790118af..65bc81306 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -158,7 +158,6 @@ create or replace type body ut_equal as member function include(a_items varchar2) return ut_equal is l_result ut_equal := self; begin - --TODO : move that logic split into get_include after removed all calls to incl and excl l_result.include_list := l_result.include_list multiset union coalesce(ut_utils.string_to_table(REPLACE(a_items,'|',','),','),ut_varchar2_list()); return l_result; end; @@ -167,7 +166,6 @@ create or replace type body ut_equal as l_result ut_equal := self; l_items ut_varchar2_list := ut_varchar2_list(); begin - --TODO : move that logic split into get_include after removed all calls to incl and excl for i in 1..a_items.count loop l_items := l_items multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_items(i),'|',','),','),ut_varchar2_list()); end loop; @@ -178,7 +176,6 @@ create or replace type body ut_equal as member function exclude(a_items varchar2) return ut_equal is l_result ut_equal := self; begin - --TODO : move that logic split into get_include after removed all calls to incl and excl l_result.exclude_list := l_result.exclude_list multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_items,'|',','),','),ut_varchar2_list()); return l_result; end; @@ -187,7 +184,6 @@ create or replace type body ut_equal as l_result ut_equal := self; l_items ut_varchar2_list := ut_varchar2_list(); begin - --TODO : move that logic split into get_include after removed all calls to incl and excl for i in 1..a_items.count loop l_items := l_items multiset union all coalesce(ut_utils.string_to_table(REPLACE(a_items(i),'|',','),','),ut_varchar2_list()); end loop; diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index c34f19a60..7045fa1d2 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -53,7 +53,6 @@ create or replace type body ut_include as l_actual ut_data_value; l_result1 integer; begin - --TODO : Join by exclude an include should show differences if self.expected.data_type = a_actual.data_type then l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, From d8525d60c8bb94ef1a1ad2a11d274078a5035e3f Mon Sep 17 00:00:00 2001 From: lwasylow Date: Sun, 2 Dec 2018 17:23:35 +0000 Subject: [PATCH 70/83] Change behaviour to compare columns regardless of column position in ref cursor. --- docs/userguide/expectations.md | 29 +++- .../data_values/ut_compound_data_helper.pkb | 91 ++++++++++-- .../data_values/ut_compound_data_helper.pks | 6 +- .../data_values/ut_compound_data_value.tpb | 2 +- .../data_values/ut_cursor_details.tpb | 27 +++- .../data_values/ut_cursor_details.tps | 4 +- .../data_values/ut_data_value_refcursor.tpb | 15 +- .../data_values/ut_data_value_refcursor.tps | 3 +- source/expectations/matchers/ut_equal.tpb | 20 ++- source/expectations/matchers/ut_equal.tps | 11 +- source/expectations/matchers/ut_include.tpb | 8 +- .../expectations/ut_expectation_compound.tpb | 18 +++ .../expectations/ut_expectation_compound.tps | 4 +- .../expectations/test_expectations_cursor.pkb | 129 ++++++++++++++++-- .../expectations/test_expectations_cursor.pks | 21 ++- 15 files changed, 328 insertions(+), 60 deletions(-) diff --git a/docs/userguide/expectations.md b/docs/userguide/expectations.md index 80a5667dc..66a352669 100644 --- a/docs/userguide/expectations.md +++ b/docs/userguide/expectations.md @@ -680,13 +680,36 @@ utPLSQL is capable of comparing compound data-types including: ### Notes on comparison of compound data - Compound data can contain elements of any data-type. This includes blob, clob, object type, nested table, varray or even a nested-cursor within a cursor. -- Cursors, nested table and varray types are compared as **ordered lists of elements**. If order of elements differ, expectation will fail. + +- Nested table and varray types are compared as **ordered lists of elements**. If order of elements differ, expectation will fail. + +- Cursors are compared as **unordered list of elements** by default. If order of elements is of importance the option has to be passed to enforce column order comparison `ordered_columns` e.g. + + ```sql + procedure ut_refcursors1 is + l_actual sys_refcursor; + l_expected sys_refcursor; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); + begin + open l_actual for select 1 user_id,'s' a_col,'test' username from dual; + open l_expected for select 'test' username,'s' a_col,1 user_id from dual; + --Act + ut3.ut.expect(l_actual).to_equal(l_expected).join_by('USER_ID').ordered_columns; + end; + ``` + - Comparison of compound data is data-type aware. So a column `ID NUMBER` in a cursor is not the same as `ID VARCHAR2(100)`, even if they both hold the same numeric values. + - Comparison of cursor columns containing `DATE` will only compare date part **and ignore time** by default. See [Comparing cursor data containing DATE fields](#comparing-cursor-data-containing-date-fields) to check how to enable date-time comparison in cursors. + - Comparison of cursor returning `TIMESTAMP` **columns** against cursor returning `TIMESTAMP` **bind variables** requires variables to be casted to proper precision. This is an Oracle SQL - PLSQL compatibility issue and usage of CAST is the only known workaround for now. -See [Comparing cursor data containing TIMESTAMP bind variables](#comparing-cursor-data-containing-timestamp-bind-variables) for examples. + See [Comparing cursor data containing TIMESTAMP bind variables](#comparing-cursor-data-containing-timestamp-bind-variables) for examples. + - To compare nested table/varray type you need to convert it to `anydata` by using `anydata.convertCollection()` + - To compare object type you need to convert it to `anydata` by using `anydata.convertObject()` + - It is possible to compare PL/SQL records, collections, varrays and associative arrays. To compare this types of data, use cursor comparison feature of utPLSQL and TABLE operator in SQL query - On Oracle 11g Release 2 - pipelined table functions are needed (see section [Implicit (Shadow) Types in this artcile](https://oracle-base.com/articles/misc/pipelined-table-functions)) - On Oracle 12c and above - use [TABLE function on nested tables/varrays/associative arrays of PL/SQL records](https://oracle-base.com/articles/12c/using-the-table-operator-with-locally-defined-types-in-plsql-12cr1) @@ -768,7 +791,7 @@ create or replace package body test_cursor_compare as from dual union all select 'M' AS GENDER, 'LUKE' as FIRST_NAME, 'SKYWALKER' AS LAST_NAME, 2 as ID, '1000' AS SALARY from dual; - ut.expect(l_actual).to_equal(l_expected); + ut.expect(l_actual).to_equal(l_expected).ordered_columns; end; end; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 49414cd11..678da0ce9 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -46,8 +46,8 @@ create or replace package body ut_compound_data_helper is end if; return l_filter; end; - - function get_columns_diff(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab) + + function get_columns_diff_ordered(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab) return tt_column_diffs is l_column_filter varchar2(32767); l_sql varchar2(32767); @@ -88,6 +88,53 @@ create or replace package body ut_compound_data_helper is return l_results; end; + function get_columns_diff_unordered(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab) + return tt_column_diffs is + l_column_filter varchar2(32767); + l_sql varchar2(32767); + l_results tt_column_diffs; + begin + with + expected_cols as + (select access_path exp_column_name,column_position exp_col_pos, + replace(column_type,'VARCHAR2','CHAR') exp_col_type_compare, column_type exp_col_type + from table(a_expected)), + actual_cols as + (select access_path act_column_name,column_position act_col_pos, + replace(column_type,'VARCHAR2','CHAR') act_col_type_compare, column_type act_col_type + from table(a_actual)), + joined_cols as + (select e.*,a.* + from expected_cols e + full outer join actual_cols a on e.exp_column_name = a.act_column_name) + select case + when exp_col_pos is null and act_col_pos is not null then '+' + when exp_col_pos is not null and act_col_pos is null then '-' + when exp_col_type_compare != act_col_type_compare then 't' + else 'p' + end as diff_type, + exp_column_name, exp_col_type, exp_col_pos, + act_column_name, act_col_type, act_col_pos + bulk collect into l_results + from joined_cols + --column is unexpected (extra) or missing + where act_col_pos is null or exp_col_pos is null + --column type is not matching (except CHAR/VARCHAR2) + or act_col_type_compare != exp_col_type_compare + order by exp_col_pos, act_col_pos; + return l_results; + end; + + function get_columns_diff(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab,a_order_enforced boolean := false) + return tt_column_diffs is + begin + if a_order_enforced then + return get_columns_diff_ordered(a_expected,a_actual); + else + return get_columns_diff_unordered(a_expected,a_actual); + end if; + end; + function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob is l_pk_value clob; begin @@ -218,10 +265,10 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(a_sql_stmt, l_sql_stmt); end; - procedure gen_sql_pieces_out_of_cursor(a_data_info ut_data_value_refcursor,a_pk_table ut_varchar2_list, a_xml_stmt out nocopy clob, + procedure gen_sql_pieces_out_of_cursor(a_data_info ut_cursor_column_tab,a_pk_table ut_varchar2_list, a_xml_stmt out nocopy clob, a_select_stmt out nocopy clob ,a_partition_stmt out nocopy clob, a_equal_stmt out nocopy clob, a_join_by_stmt out nocopy clob, a_not_equal_stmt out nocopy clob) is - l_cursor_info ut_cursor_column_tab := a_data_info.cursor_details.cursor_info; + l_cursor_info ut_cursor_column_tab := a_data_info; l_partition_tmp clob; l_col_name varchar2(100); begin @@ -305,7 +352,7 @@ create or replace package body ut_compound_data_helper is begin dbms_lob.createtemporary(l_compare_sql, true); - gen_sql_pieces_out_of_cursor(a_other, a_join_by_list, + gen_sql_pieces_out_of_cursor(a_other.cursor_details.cursor_info, a_join_by_list, l_xmltable_stmt, l_select_stmt, l_partition_stmt, l_equal_stmt, l_join_on_stmt, l_not_equal_stmt); @@ -374,9 +421,8 @@ create or replace package body ut_compound_data_helper is function get_rows_diff_by_sql(a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, - a_join_by_list ut_varchar2_list, a_unordered boolean + a_join_by_list ut_varchar2_list, a_unordered boolean, a_enforce_column_order boolean := false ) return tt_row_diffs is - l_act_col_filter varchar2(32767); l_exp_col_filter varchar2(32767); l_act_extract_xpath varchar2(32767):= ut_utils.to_xpath(get_column_extract_path(a_act_cursor_info)); @@ -412,25 +458,28 @@ create or replace package body ut_compound_data_helper is select rn, diff_type, diffed_row, pk_value ,case when diff_type = 'Actual:' then 1 else 2 end rnk ,1 final_order + ,col_name from ( ]'; if a_unordered then - l_sql := l_sql || q'[select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value pk_value + l_sql := l_sql || q'[select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, pk_value,col_name from - (select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item + (select nvl(exp.rn, act.rn) rn, nvl(exp.pk_value, act.pk_value) pk_value, exp.col exp_item, act.col act_item , + nvl(exp.col_name,act.col_name) col_name from exp join act on exp.rn = act.rn and exp.col_name = act.col_name where dbms_lob.compare(exp.col_val, act.col_val) != 0) unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:') ))]'; else - l_sql := l_sql || q'[ select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, null pk_value + l_sql := l_sql || q'[ select rn, diff_type, xmlserialize(content data_item no indent) diffed_row, null pk_value,col_name from (select nvl(exp.rn, act.rn) rn, xmlagg(exp.col order by exp.col_no) exp_item, - xmlagg(act.col order by act.col_no) act_item + xmlagg(act.col order by act.col_no) act_item, + max(nvl(exp.col_name,act.col_name)) col_name from exp exp join act act on exp.rn = act.rn and exp.col_name = act.col_name where dbms_lob.compare(exp.col_val, act.col_val) != 0 - group by exp.rn, act.rn + group by (exp.rn, act.rn) ) unpivot ( data_item for diff_type in (exp_item as 'Expected:', act_item as 'Actual:')) )]'; @@ -443,14 +492,26 @@ create or replace package body ut_compound_data_helper is nvl2(:join_by,ut_compound_data_helper.get_pk_value(:join_by,case when exp_data_id is null then act_item_data else exp_item_data end),null) pk_value ,case when exp_data_id is null then 1 else 2 end rnk ,2 final_order + ,null col_name from ut_compound_data_diff_tmp i where diff_id = :diff_id and act_data_id is null or exp_data_id is null ) - order by final_order, - case when final_order = 1 then rn else rnk end, - case when final_order = 1 then rnk else rn end ]'; + order by final_order,]'; + if a_enforce_column_order then + l_sql := l_sql ||q'[case when final_order = 1 then rn else rnk end, + case when final_order = 1 then rnk else rn end ]'; + elsif not(a_enforce_column_order) and not(a_unordered) then + l_sql := l_sql ||q'[case when final_order = 1 then rn else rnk end, + case when final_order = 1 then rnk else rn end ]'; + elsif a_unordered then + l_sql := l_sql ||q'[case when final_order = 1 then col_name else to_char(rnk) end, + case when final_order = 1 then to_char(rn) else col_name end, + case when final_order = 1 then to_char(rnk) else col_name end + ]'; + end if; + execute immediate l_sql bulk collect into l_results using l_exp_extract_xpath,l_join_xpath,a_diff_id, a_expected_dataset_guid, diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 80bae9c36..290c101cc 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -57,13 +57,13 @@ create or replace package ut_compound_data_helper authid definer is ); type t_diff_tab is table of t_diff_rec; - + function get_columns_filter( a_exclude_xpath varchar2, a_include_xpath varchar2, a_table_alias varchar2 := 'ucd', a_column_alias varchar2 := 'item_data' ) return varchar2; - function get_columns_diff(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab) + function get_columns_diff(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab,a_order_enforced boolean := false) return tt_column_diffs; function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob; @@ -75,7 +75,7 @@ create or replace package ut_compound_data_helper authid definer is function get_rows_diff_by_sql(a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, - a_join_by_list ut_varchar2_list, a_unordered boolean + a_join_by_list ut_varchar2_list, a_unordered boolean, a_enforce_column_order boolean := false ) return tt_row_diffs; subtype t_hash is raw(128); diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 81e9d8c39..a8323eecd 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -223,7 +223,7 @@ create or replace type body ut_compound_data_value as end loop; ut_compound_data_helper.set_rows_diff(l_sql_rowcount); - --result is OK only if both are same + --result is OK only if both are same if l_sql_rowcount = 0 and ( self.elements_count = l_other.elements_count or a_inclusion_compare )then l_result := 0; else diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index eba4bc884..9f9f4bb52 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -2,13 +2,21 @@ create or replace type body ut_cursor_details as order member function compare(a_other ut_cursor_details) return integer is l_diffs integer; - begin - select count(1) into l_diffs - from table(self.cursor_info) a full outer join table(a_other.cursor_info) e - on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and - REPLACE(a.column_type,'VARCHAR2','CHAR') = REPLACE(e.column_type,'VARCHAR2','CHAR') - and a.column_position = e.column_position ) - where a.column_name is null or e.column_name is null; + begin + if self.is_column_order_enforced = 1 then + select count(1) into l_diffs + from table(self.cursor_info) a full outer join table(a_other.cursor_info) e + on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and + REPLACE(a.column_type,'VARCHAR2','CHAR') = REPLACE(e.column_type,'VARCHAR2','CHAR') + and a.column_position = e.column_position ) + where a.column_name is null or e.column_name is null; + else + select count(1) into l_diffs + from table(self.cursor_info) a full outer join table(a_other.cursor_info) e + on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and + REPLACE(a.column_type,'VARCHAR2','CHAR') = REPLACE(e.column_type,'VARCHAR2','CHAR')) + where a.column_name is null or e.column_name is null; + end if; return l_diffs; end; @@ -221,5 +229,10 @@ create or replace type body ut_cursor_details as return; end; + member procedure ordered_columns(self in out nocopy ut_cursor_details,a_ordered_columns boolean := false) is + begin + self.is_column_order_enforced := ut_utils.boolean_to_int(a_ordered_columns); + end; + end; / diff --git a/source/expectations/data_values/ut_cursor_details.tps b/source/expectations/data_values/ut_cursor_details.tps index b38fec0fb..a64a6dd55 100644 --- a/source/expectations/data_values/ut_cursor_details.tps +++ b/source/expectations/data_values/ut_cursor_details.tps @@ -1,6 +1,7 @@ create or replace type ut_cursor_details force authid current_user as object ( cursor_info ut_cursor_column_tab, + is_column_order_enforced number(1,0), order member function compare(a_other ut_cursor_details) return integer, member procedure get_anytype_members_info(a_anytype anytype, a_attribute_typecode out pls_integer, a_schema_name out varchar2, a_type_name out varchar2, a_len out pls_integer,a_elements_count out pls_integer), @@ -15,6 +16,7 @@ create or replace type ut_cursor_details force authid current_user as object member function get_user_defined_type(a_data anydata) return anytype, constructor function ut_cursor_details(self in out nocopy ut_cursor_details) return self as result, constructor function ut_cursor_details(self in out nocopy ut_cursor_details,a_cursor_number in number) - return self as result + return self as result, + member procedure ordered_columns(self in out nocopy ut_cursor_details,a_ordered_columns boolean := false) ) / diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index b2314cf48..c62163758 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -141,6 +141,8 @@ create or replace type body ut_data_value_refcursor as l_row_diffs ut_compound_data_helper.tt_row_diffs; l_message varchar2(32767); + l_column_order_enforce boolean := ut_utils.int_to_boolean(self.cursor_details.is_column_order_enforced); + function get_col_diff_text(a_col ut_compound_data_helper.t_column_diffs) return varchar2 is begin return @@ -208,8 +210,8 @@ create or replace type body ut_data_value_refcursor as dbms_lob.createtemporary(l_result,true); --diff columns if not self.is_null and not l_actual.is_null then - l_column_diffs := ut_compound_data_helper.get_columns_diff(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info); - + l_column_diffs := ut_compound_data_helper.get_columns_diff(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info,l_column_order_enforce); + if l_column_diffs.count > 0 then ut_utils.append_to_clob(l_result,chr(10) || 'Columns:' || chr(10)); end if; @@ -234,9 +236,9 @@ create or replace type body ut_data_value_refcursor as -- First tell how many rows are different l_diff_row_count := ut_compound_data_helper.get_rows_diff_count; l_results := ut_utils.t_clob_tab(); - if l_diff_row_count > 0 then + if l_diff_row_count > 0 then l_row_diffs := ut_compound_data_helper.get_rows_diff_by_sql( - l_exp_cols,l_act_cols, self.data_id, l_actual.data_id, l_diff_id,a_join_by_list , a_unordered); + l_exp_cols,l_act_cols, self.data_id, l_actual.data_id, l_diff_id,a_join_by_list , a_unordered, l_column_order_enforce); l_message := chr(10) ||'Rows: [ ' || l_diff_row_count ||' differences' || case when l_diff_row_count > c_max_rows and l_row_diffs.count > 0 then ', showing first '||c_max_rows end @@ -248,7 +250,7 @@ create or replace type body ut_data_value_refcursor as end loop; ut_utils.append_to_clob(l_result,l_results); else - l_message:= chr(10)||'Rows: [ all different ]'||chr(10)||' All rows are different as the columns are not matching.'; + l_message:= chr(10)||'Rows: [ all different ]'||chr(10)||' All rows are different as the columns position is not matching.'; ut_utils.append_to_clob( l_result, l_message ); end if; else @@ -304,11 +306,12 @@ create or replace type body ut_data_value_refcursor as return self.elements_count = 0; end; - member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor is + member function update_cursor_details (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list,a_ordered_columns boolean := false) return ut_data_value_refcursor is l_result ut_data_value_refcursor := self; begin if l_result.cursor_details.cursor_info is not null then l_result.cursor_details.cursor_info := ut_compound_data_helper.inc_exc_columns_from_cursor(l_result.cursor_details.cursor_info,a_exclude_xpath,a_include_xpath); + l_result.cursor_details.ordered_columns(a_ordered_columns); end if; return l_result; end; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tps b/source/expectations/data_values/ut_data_value_refcursor.tps index c3270270f..d8fb2c891 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tps +++ b/source/expectations/data_values/ut_data_value_refcursor.tps @@ -38,5 +38,6 @@ create or replace type ut_data_value_refcursor under ut_compound_data_value( overriding member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean := false, a_is_negated boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return integer, overriding member function is_empty return boolean, - member function filter_cursor (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) return ut_data_value_refcursor) + member function update_cursor_details (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list,a_ordered_columns boolean := false) return ut_data_value_refcursor +) / diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index 65bc81306..d575dc36c 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -253,6 +253,18 @@ create or replace type body ut_equal as begin return ( coalesce(join_columns, ut_varchar2_list()) ); end; + + member function ordered_columns return ut_equal is + l_result ut_equal := self; + begin + l_result.is_column_order_enforced := ut_utils.boolean_to_int(true); + return l_result; + end; + + member function get_ordered_columns return boolean is + begin + return ut_utils.int_to_boolean(nvl(is_column_order_enforced,0)); + end; overriding member function run_matcher(self in out nocopy ut_equal, a_actual ut_data_value) return boolean is l_result boolean; @@ -262,8 +274,8 @@ create or replace type body ut_equal as if self.expected is of (ut_data_value_anydata) then l_result := 0 = treat(self.expected as ut_data_value_anydata).compare_implementation(a_actual, get_exclude_xpath(), get_include_xpath()); elsif self.expected is of (ut_data_value_refcursor) then - l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); - l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, get_unordered(), false, false, get_join_by_list() ); + l_actual := treat(a_actual as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,get_ordered_columns()); + l_result := 0 = treat(self.expected as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,get_ordered_columns()).compare_implementation(l_actual, get_unordered(), false, false, get_join_by_list()); else l_result := equal_with_nulls((self.expected = a_actual), a_actual); end if; @@ -280,10 +292,10 @@ create or replace type body ut_equal as begin if self.expected.data_type = a_actual.data_type and self.expected.is_diffable then if self.expected is of (ut_data_value_refcursor) then - l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); + l_actual := treat(a_actual as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,get_ordered_columns()); l_result := 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() - || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).filter_cursor(exclude_list, include_list).diff(l_actual, get_unordered(),get_join_by_list()); + || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,get_ordered_columns()).diff(l_actual, get_unordered(),get_join_by_list()); else l_result := 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() diff --git a/source/expectations/matchers/ut_equal.tps b/source/expectations/matchers/ut_equal.tps index e53fda40b..de8fa4561 100644 --- a/source/expectations/matchers/ut_equal.tps +++ b/source/expectations/matchers/ut_equal.tps @@ -1,4 +1,4 @@ -create or replace type ut_equal under ut_comparison_matcher( +create or replace type ut_equal force under ut_comparison_matcher( /* utPLSQL - Version 3 Copyright 2016 - 2018 utPLSQL Project @@ -42,6 +42,11 @@ create or replace type ut_equal under ut_comparison_matcher( */ join_on_list ut_varchar2_list, + /** + * Flag to force cursor comparision into ordered mode + */ + is_column_order_enforced number(1,0), + member procedure init(self in out nocopy ut_equal, a_expected ut_data_value, a_nulls_are_equal boolean), member function equal_with_nulls( self in ut_equal, a_assert_result boolean, a_actual ut_data_value) return boolean, constructor function ut_equal(self in out nocopy ut_equal, a_expected anydata, a_nulls_are_equal boolean := null) return self as result, @@ -75,7 +80,9 @@ create or replace type ut_equal under ut_comparison_matcher( member function get_join_by_list return ut_varchar2_list, overriding member function run_matcher(self in out nocopy ut_equal, a_actual ut_data_value) return boolean, overriding member function failure_message(a_actual ut_data_value) return varchar2, - overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2 + overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2, + member function ordered_columns return ut_equal, + member function get_ordered_columns return boolean ) not final / diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index 7045fa1d2..a0e463184 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -54,8 +54,8 @@ create or replace type body ut_include as l_result1 integer; begin if self.expected.data_type = a_actual.data_type then - l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); - l_result := 0 = treat(self.expected as ut_data_value_refcursor).filter_cursor(exclude_list, include_list).compare_implementation(l_actual, + l_actual := treat(a_actual as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,self.get_ordered_columns()); + l_result := 0 = treat(self.expected as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,self.get_ordered_columns()).compare_implementation(l_actual, true,self.get_inclusion_compare(), self.get_negated(), self.get_join_by_list()); else l_result := (self as ut_matcher).run_matcher(a_actual); @@ -73,10 +73,10 @@ create or replace type body ut_include as l_actual ut_data_value; begin if self.expected.data_type = a_actual.data_type and self.expected.is_diffable then - l_actual := treat(a_actual as ut_data_value_refcursor).filter_cursor(exclude_list, include_list); + l_actual := treat(a_actual as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,self.get_ordered_columns()); l_result := 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() - || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).filter_cursor(self.exclude_list, self.include_list).diff(l_actual, true, self.get_join_by_list()); + || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,self.get_ordered_columns()).diff(l_actual, true, self.get_join_by_list()); else l_result := (self as ut_matcher).failure_message(a_actual) || ': '|| self.expected.to_string_report(); end if; diff --git a/source/expectations/ut_expectation_compound.tpb b/source/expectations/ut_expectation_compound.tpb index b34b97c85..d899c87a3 100644 --- a/source/expectations/ut_expectation_compound.tpb +++ b/source/expectations/ut_expectation_compound.tpb @@ -227,5 +227,23 @@ create or replace type body ut_expectation_compound as end if; end; + member function ordered_columns return ut_expectation_compound is + l_result ut_expectation_compound; + begin + l_result := self; + l_result.matcher := treat(l_result.matcher as ut_equal).ordered_columns; + return l_result; + end; + + member procedure ordered_columns(self in ut_expectation_compound) is + begin + + if ut_utils.int_to_boolean(negated) then + self.not_to( treat(matcher as ut_equal).ordered_columns ); + else + self.to_( treat(matcher as ut_equal).ordered_columns ); + end if; + end; + end; / diff --git a/source/expectations/ut_expectation_compound.tps b/source/expectations/ut_expectation_compound.tps index ffeb1c056..6dd34e077 100644 --- a/source/expectations/ut_expectation_compound.tps +++ b/source/expectations/ut_expectation_compound.tps @@ -48,7 +48,9 @@ create or replace type ut_expectation_compound under ut_expectation( member function join_by(a_columns varchar2) return ut_expectation_compound, member function join_by(a_columns ut_varchar2_list) return ut_expectation_compound, member procedure join_by(self in ut_expectation_compound, a_columns varchar2), - member procedure join_by(self in ut_expectation_compound, a_columns ut_varchar2_list) + member procedure join_by(self in ut_expectation_compound, a_columns ut_varchar2_list), + member function ordered_columns return ut_expectation_compound, + member procedure ordered_columns(self in ut_expectation_compound) ) final / diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index 5e786ff21..d38dfb402 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -300,11 +300,48 @@ create or replace package body test_expectations_cursor is open l_expected for select 1 as col_1, 2 as col_2 from dual; open l_actual for select 2 as col_2, 1 as col_1 from dual; --Act - ut3.ut.expect( l_actual ).to_equal( l_expected ); + ut3.ut.expect( l_actual ).to_equal( l_expected ).ordered_columns; --Assert ut.expect(expectations.failed_expectations_data()).not_to_be_empty(); end; + procedure pass_on_different_column_order + as + l_expected sys_refcursor; + l_actual sys_refcursor; + begin + --Arrange + open l_expected for select 1 as col_1, 2 as col_2 from dual; + open l_actual for select 2 as col_2, 1 as col_1 from dual; + --Act + ut3.ut.expect( l_actual ).to_equal( l_expected ); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + + procedure fail_on_multi_diff_col_order + as + l_expected sys_refcursor; + l_actual sys_refcursor; + l_actual_message varchar2(32767); + l_expected_message varchar2(32767); + begin + --Arrange + open l_expected for select 1 as col_1, 2 as col_2,3 as col_3, 4 as col_4,5 col_5 from dual; + open l_actual for select 2 as col_2, 1 as col_1,40 as col_4, 5 as col_5, 30 col_3 from dual; + --Act + ut3.ut.expect( l_actual ).to_equal( l_expected ); + --Assert + l_expected_message := q'[Actual: refcursor [ count = 1 ] was expected to equal: refcursor [ count = 1 ] +%Diff: +%Rows: [ 1 differences ] +%Row No. 1 - Actual: 4030 +%Row No. 1 - Expected: 34]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + end; + procedure fail_on_different_row_order as l_expected sys_refcursor; @@ -600,14 +637,14 @@ Rows: [ 1 differences ] open l_actual for select to_char(rownum) rn, rownum another_rn from dual connect by level <=2; open l_expected for select rownum rn, rownum another_rn from dual connect by level <=2; --Act - ut3.ut.expect(l_actual).to_equal(l_expected); + ut3.ut.expect(l_actual).to_equal(l_expected).ordered_columns; l_expected_message := q'[Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ] Diff: Columns: Column data-type is invalid. Expected: NUMBER, actual: VARCHAR2. Rows: [ all different ] - All rows are different as the columns are not matching.]'; + All rows are different as the columns position is not matching.]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -635,7 +672,6 @@ Columns:% ut.expect(l_actual_message).to_be_like(l_expected_message); end; - --%test(Reports column diff on cusror with different column positions) procedure column_diff_on_col_position is l_actual sys_refcursor; l_expected sys_refcursor; @@ -646,7 +682,7 @@ Columns:% open l_actual for select rownum+1 col_1, rownum+2 col_2, rownum+3 col_3, rownum+4 col_4 from dual connect by level <=2; open l_expected for select rownum+1 col_1, rownum+4 col_4, rownum+2 col_2, rownum+3 col_3 from dual connect by level <=2; --Act - ut3.ut.expect(l_actual).to_equal(l_expected); + ut3.ut.expect(l_actual).to_equal(l_expected).ordered_columns; l_expected_message := q'[Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ] Diff: @@ -655,12 +691,26 @@ Columns: Column is misplaced. Expected position: 3, actual position: 2. Column is misplaced. Expected position: 4, actual position: 3. Rows: [ all different ] - All rows are different as the columns are not matching.]'; + All rows are different as the columns position is not matching.]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); end; + procedure column_diff_on_col_pos_unord is + l_actual sys_refcursor; + l_expected sys_refcursor; + l_actual_message varchar2(32767); + l_expected_message varchar2(32767); + begin + --Arrange + open l_actual for select rownum+1 col_1, rownum+2 col_2, rownum+3 col_3, rownum+4 col_4 from dual connect by level <=2; + open l_expected for select rownum+1 col_1, rownum+4 col_4, rownum+2 col_2, rownum+3 col_3 from dual connect by level <=2; + --Act + ut3.ut.expect(l_actual).to_equal(l_expected); + + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; --%test(Reports only mismatched columns on column data mismatch) procedure data_diff_on_col_data_mismatch is @@ -741,7 +791,7 @@ Rows: [ 60 differences, showing first 20 ] select 'F' AS GENDER, 'JESSICA' as FIRST_NAME, 'JONES' AS LAST_NAME, 4 as ID, '2345' AS SALARY from dual union all select 'M' AS GENDER, 'LUKE' as FIRST_NAME, 'SKYWALKER' AS LAST_NAME, 2 as ID, '1000' AS SALARY from dual; --Act - ut3.ut.expect(l_actual).to_equal(l_expected); + ut3.ut.expect(l_actual).to_equal(l_expected).ordered_columns; l_expected_message := q'[Actual: refcursor [ count = 4 ] was expected to equal: refcursor [ count = 3 ] Diff: Columns: @@ -761,6 +811,42 @@ Rows: [ 4 differences ] ut.expect(l_actual_message).to_be_like(l_expected_message); end; + procedure col_and_data_diff_not_ordered is + l_actual sys_refcursor; + l_expected sys_refcursor; + l_actual_message varchar2(32767); + l_expected_message varchar2(32767); + begin + --Arrange + open l_expected for + select 1 as ID, 'JACK' as FIRST_NAME, 'SPARROW' AS LAST_NAME, 10000 AS SALARY from dual union all + select 2 as ID, 'LUKE' as FIRST_NAME, 'SKYWALKER' AS LAST_NAME, 1000 AS SALARY from dual union all + select 3 as ID, 'TONY' as FIRST_NAME, 'STARK' AS LAST_NAME, 100000 AS SALARY from dual; + open l_actual for + select 'M' AS GENDER, 'JACK' as FIRST_NAME, 'SPARROW' AS LAST_NAME, 1 as ID, '25000' AS SALARY from dual union all + select 'M' AS GENDER, 'TONY' as FIRST_NAME, 'STARK' AS LAST_NAME, 3 as ID, '100000' AS SALARY from dual union all + select 'F' AS GENDER, 'JESSICA' as FIRST_NAME, 'JONES' AS LAST_NAME, 4 as ID, '2345' AS SALARY from dual union all + select 'M' AS GENDER, 'LUKE' as FIRST_NAME, 'SKYWALKER' AS LAST_NAME, 2 as ID, '1000' AS SALARY from dual; + --Act + ut3.ut.expect(l_actual).to_equal(l_expected); + l_expected_message := q'[Actual: refcursor [ count = 4 ] was expected to equal: refcursor [ count = 3 ] +Diff: +Columns: + Column data-type is invalid. Expected: NUMBER, actual: VARCHAR2. + Column [position: 1, data-type: CHAR] is not expected in results. +Rows: [ 4 differences ] + Row No. 1 - Actual: 25000 + Row No. 1 - Expected: 10000 + Row No. 2 - Actual: TONYSTARK3100000 + Row No. 2 - Expected: 2LUKESKYWALKER1000 + Row No. 3 - Actual: JESSICAJONES42345 + Row No. 3 - Expected: 3TONYSTARK100000 + Row No. 4 - Extra: MLUKESKYWALKER21000]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + end; + procedure prepare_table as pragma autonomous_transaction; @@ -965,7 +1051,7 @@ Rows: [ 4 differences ] open l_actual for select '1' , '2' from dual connect by level <=2; open l_expected for select rownum , rownum expected_column_name from dual connect by level <=2; --Act - ut3.ut.expect(l_actual).to_equal(l_expected); + ut3.ut.expect(l_actual).to_equal(l_expected).ordered_columns; l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ] %Diff: @@ -975,7 +1061,7 @@ Rows: [ 4 differences ] %Column <1> [position: 1, data-type: CHAR] is not expected in results. %Column <2> [position: 2, data-type: CHAR] is not expected in results. %Rows: [ all different ] -%All rows are different as the columns are not matching.]'; +%All rows are different as the columns position is not matching.]'; l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); @@ -1051,6 +1137,31 @@ Rows: [ 4 differences ] ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + procedure cursor_joinby_col_not_ord + as + l_expected sys_refcursor; + l_actual sys_refcursor; + l_actual_message varchar2(32767); + l_expected_message varchar2(32767); + begin + --Arrange + open l_expected for select 1 as col_1, 2 as col_2,3 as col_3, 4 as col_4,5 col_5 from dual; + open l_actual for select 2 as col_2, 1 as col_1,40 as col_4, 5 as col_5, 30 col_3 from dual; + --Act + ut3.ut.expect( l_actual ).to_equal( l_expected ).join_by('COL_1'); + --Assert + l_expected_message := q'[Actual: refcursor [ count = 1 ] was expected to equal: refcursor [ count = 1 ] +%Diff: +%Rows: [ 1 differences ] +%PK 1 - Actual: 30 +%PK 1 - Expected: 3 +%PK 1 - Actual: 40 +%PK 1 - Expected: 4]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + end; + procedure cursor_joinby_compare_twocols is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index ae52d741c..a4db867ae 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -68,9 +68,15 @@ create or replace package test_expectations_cursor is --%test(Gives failure when different column name is used in cursors) procedure fail_on_different_column_name; - --%test(Gives failure when different column ordering is used in cursors) + --%test(Gives failure when different column ordering is used in cursors when enforced column order) procedure fail_on_different_column_order; + --%test(Pass when different column ordering is used in cursors) + procedure pass_on_different_column_order; + + --%test(Fail and highlight diffrence between columns when columns are unordered and different value) + procedure fail_on_multi_diff_col_order; + --%test(Gives failure when different row ordering is used in cursors) procedure fail_on_different_row_order; @@ -131,18 +137,24 @@ create or replace package test_expectations_cursor is --%test(Reports column diff on cursor with different column name) procedure column_diff_on_col_name_diff; - --%test(Reports column diff on cursor with different column positions) + --%test(Reports column diff on cursor with different column positions when column order is enforced) procedure column_diff_on_col_position; + --%test(Reports column diff on cursor with different column positions) + procedure column_diff_on_col_pos_unord; + --%test(Reports only mismatched columns on row data mismatch) procedure data_diff_on_col_data_mismatch; --%test(Reports only first 20 rows of diff and gives a full diff count) procedure data_diff_on_20_rows_only; - --%test(Reports data diff and column diff when both are different) + --%test(Reports data diff and column diff when both are different with enforced ordered columns) procedure column_and_data_diff; + --%test(Reports data diff and column diff when both are different when columns are not ordered) + procedure col_and_data_diff_not_ordered; + procedure prepare_table; procedure cleanup_table; @@ -199,6 +211,9 @@ create or replace package test_expectations_cursor is --%test( Compare cursors join by single key ) procedure cursor_joinby_compare; + --%test(Compare cursors by single key with unordered columns position) + procedure cursor_joinby_col_not_ord; + --%test( Compare cursors join by composite key) procedure cursor_joinby_compare_twocols; From 48ad81e7d572e8573328535590c88fe508bebe87 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Fri, 7 Dec 2018 12:53:03 +0000 Subject: [PATCH 71/83] Small fixes and updates regarding peer review. Updated documentation --- docs/images/venn21.gif | Bin 0 -> 3213 bytes docs/images/venn22.gif | Bin 0 -> 3482 bytes docs/userguide/advanced_data_comparison.md | 4 +- docs/userguide/expectations.md | 67 +++++++++++++++--- source/core/types/ut_cursor_info.tps | 22 ------ source/core/ut_utils.pkb | 5 -- source/core/ut_utils.pks | 3 - .../data_values/ut_compound_data_helper.pkb | 4 +- .../data_values/ut_cursor_column.tps | 14 ++-- .../data_values/ut_cursor_details.tpb | 16 ++--- .../data_values/ut_cursor_details.tps | 2 +- .../data_values/ut_data_value_refcursor.tpb | 22 +++--- 12 files changed, 88 insertions(+), 71 deletions(-) create mode 100644 docs/images/venn21.gif create mode 100644 docs/images/venn22.gif delete mode 100644 source/core/types/ut_cursor_info.tps diff --git a/docs/images/venn21.gif b/docs/images/venn21.gif new file mode 100644 index 0000000000000000000000000000000000000000..0efecae076a09e18dfb67f0b430e8e251e620d55 GIT binary patch literal 3213 zcmeH`>pxTp1IN#qb7tlYLx&l185;Llp%IBl2ZI@5N2W}r{Y)<9-c%}Cab}ELrW%)W z$!au;VvFczZ^vzy+A?9$QmKUQY1P`c@;v*zeEx?0z4*QPz50DWpKq`r$kS_kF|Zvd z0R9OK!w7=V>2wrDnM|gMi3y9vVzb${wzeD&$H~cw%jLSeyL)#XO4F(0x1R1THgQXu=xf#da*Q3IW5Bso-(SXwthGIN>CDXvuGb}{pzUl}iQBGc z6a8)u1E;WUALt?NoW8oC6_(rIk^&JrlWmJ(m(Op6X>3s+O6t|M4=&B*WtJA*ZCfTA zUJ%MUagx4E3UVig!dMpY_Srq}9%`AXlYh!JEe^;i#=gUV|6KEC*P(^z+Rs!>NL2_Yw~G#SL99kY^LV2==k zoYf9i;qz7LEC!Z>5%9>|0c$?%+4Mst<#&FBo*}9QW8dD2GR|2eln~TF_xuUf^wY72 zIc6K&d#Gf|2c_yFg>y3kWmUZI?KcNFWbV1P3=5{B2+_1gU=*vHdtz+ zeNyBWEyPF`YDv^rIaMtni5w?|QWMvlvpM;RCL@8Sp$F~>tWl!V(Cb41DcX8Lr3qT2 z(Bhy|OTW7M*!?m4!u1J@Lad@<%UKLQo#}apPU92Zr3U_LLeI}%Cq5{-+C&5Ce#|`i zjb#;v>i}}Q6eY1=6hLA)$?TfM`$HP8{USK|ELWSBu7LHq9!dGsEcN)cURtLgDZ6O( zuBHp86E*sDA(6;OH%vh!%Q*8~ur#DEB05*~(5p5>6_@#Sh;)oMOV{qpL#y(bZYFqrRfT0u@bu2US_1A*plYk_gUy6Ee{ zYf!Eth`$|O2yzsvh9OtweFG{>UF(99>CF+a-3f&PaH&!FlP~Q}hrtuKYtkqd(sl(P zsB|X*M^C!<0BbGc0GNxH`@J;LTSYuI?*%#q2-4myp!ZD->O-_y9J9-+&jn5Y>ggd_ z?2b3or=We5@JF)g_!WVCln-JtZN&=;i1xS;#&$Rr)4-trN)3jemg}Nn95+`vM&H?4 zyf7fsW?~shLq9I5bwJXGa4b$zYF2Ym?re%MRD^;8u)*b1QS?P-gHJJ=U05Gct?Teu zW@N%=uWqN){(e`Qi%n8JC-k5$sxvtMt%o*bgok1!WTc*Icl|zfF9&@-4?qA481A0R zg`~T8Y^K}%B$1*}emz1GYeLc!j15S5j$J$7Ks8+kgw6=av#j16 zywYrWk~o=eb<1#_ZVUxk2&gl-`@WvMP!JOYfQzg$P$t3)man;`cbb1e*pc#;MkL43 zbC*BeYqi#|w8^zbztgGBW4mzIe?SZs(WUuh`^u20+Q5W{zs=+Ww-1--6Ucgjc-$}S zu#LVck@PC%d@kQH@(<)8XqB-so{4>{E}5*^`tnRx%LrgR(VkMRw?U>1A$15wQYj&K z6O6d5F2|vY(m6cQ$a_otVrpdjAJ)Y21)ZwuZ3184zN%zuM}MBt_Oc(#e-Cxr+R^CO zNJjXziSLsb_R6*lQ?Lt6;u;TcfXO;yvml-dc-uQA`Jww&U^ME9?OP7NIOJ?=E16wfJ^SDx5 zcHt&dQxeURjU$b?_>gy+o)D1PYt*|OEzh6L{upDl76(86R(RBn3sPVdpd=9RN)&R5 zy|ySdsBBSfFoY<$*G=bxvTwR;N{{ZFqR_ta0n$Y#ASmVos1`>gIApbm9O;Rz?)A+vpHK&S z{A^w=n!4h1x1rXPlYEljx+ik_`i1`9lC|@-qaSCO4r4brlD2-o=G|}B7RiHQsk;yP ziTtbb&JTony!%{hc0u{_%ALBjf#Qeb$?FGh#iZ7bbtHYWarLP$dDG#4c8q^|wf|T@ zKkw(Usn5|Tqt<;V&PW@N4KtsuHuA138hqDV;Bv<9snFL|0{;R9<~s;Wj(#sNFzdPV zcAcxnVO6P|8XC!_s&CN3%Ngr(Kie+nfMfuJjwE1!g}O67oA|&ilFBarR0Jsr_*p!U z21;X2WQ^fc)So&I#{$4<(Z}r5h3xsP>`*QiV08@uE_}yN(m$J%XodRaf1%9|Eob9$ z7${yEfkWEH`NMG=K5@Nd%km~cAnug)+Q|S|Y9xyI8hnzuaMi$5x{cwQ4QdZ9y#skn pl9*zd3y@>{Fl=Pzp!so}Gk1stk{Fg6lU*L=1%iP0e*hiSTP9j84`$qlwwfOC@4E2KxB|n zL8TfB%BVsFu|jcEpoB@8rLAJ*AhnKQwbr&ar#*M)f9Sec7w_HrJ_$j7z{>NR~L`R69@z{nM|Qjs8lMAMx)c|34z`#Hb zhZ7na8WtAD=kp^YBcr3E1pD2K_xA1E2!ad@3=9qq4i68j)#|aavGMWoyLazS zPEKkO?XzdkoeZ{&)m5!l`@gLJ+P?(;kAUra3>p9qaQWx@PbYw`7C^dGPP?){ zSJ%WjTHRhZP(ZNfkrfSJ4HZ$`Qtqoe>W52d0fkg<1%0T3@kvYci0biZ<%WdOTJH7B zK{cBXJ-t72-R{l>R<6F)`$J7r^}$8+sTJrTMPpd_az&7}?VTCAu<~jQ3Tr1;)Ok34dfJzXkDL?+54A`qgbDtOS7j#mQ< z?tu|Hg-YocT}~DbxyYg69ADnT@1d; zLIyJ*T6V;_`@ty5nigtWj384q{%NS#3^``zYkFL;JznE?XwG52{Dhh7qkdo`FL)@N zKYDZTzIPsv7InWX542-%XSTD_*ZbZiVvUP+mL#^8?`#hkhlwdNv&EYUr>w1|2$qMj zAeCE8FhQa7h}Sx_If!~x$V~7!X@jaOe-_rU^Hs>ubE>Tkt@c}3{>UHkd5H9<-Day5I1R2Mdk4O( zt%5d_@_mH0{U|-&ESc6cWM1GdA6_^7<4c@JU*LwtMVX|Kkz5#ITqykvE;t@w%S75K2Rv+eFxX?9Ef=vio=9=k6XC1))vg4#Yjw;VvDtX%(6c= zYbG~YRTvn%+$o>_=u4NQ9BfS?2|aYnVH!Gm@Xe<>)Xt3BP-+HD`uS?ntaMc6c47)r z-4fjl38um%9rt(E(|1qm$4wC>-Ww~RmQp#qG@m;NQY_Q=$*>O!MAG9PCSlt+*0X)Y zPf0#~+k%bCB@e35oePs9mz1=966VZCjq?V<>!6|XWrDTZaVG3*V?-U9S=mwz3bk@6Qt+b zlo&DqhT2p+sN~A$a(C&7jkoPYfnCp& zdpx&9Ipzeu_L1r!%Fl8b4K%>sTLv9yex_4*$N>nrBQsN_*|p=k_$Q~kVq&p6=+*w9 z;=c({cRNN#TaZq)2c69ppXKY>l9IkAnk-K{O(#5_-`QLrsE@%Y=xPHIN-L$FYteg;~{qGSdQ8LMPm0(wNBxa>~u0G4;lQtgTLMI#o4s^M0)KBHp+wffEUya|h(`@^3(}t3BHYm26y-RzXN8VPaZ#qIyE=WqyVYrTGrXyy1@M%dbtVxTcbtyakKzhj$;zcbhPj95INz z$To6yTfPFFrN#7(&i7s!g{=pAh1Ubgj4Ql5nMj7qH*|T>d7

IPR9KGO%Op+X3b&OG+2DfrawyVv@9DF%2 zHvhvq13I$6o`R)^RZ0vqYsMm63T;MG7gII9cm9x~$&*`+?ab7k-LPb%iNX^Z!2HLR$>wH)*ia|NNE7G-|4 zPWaW@uxGU=E3X@coAm#fuuf-+6%b*^3IlpD+Ej`*{2P(Re$gEE%p{su`9;*DJ>sbZ z4caNslt%Zj^pnhWU~n*)?+2GLuqDI9g}>8s4Fn2^?68o-Z+QcB6ri!qZOs7<RCI^R=zEVYT0U$ragut}WPC#NxBJuQ!t4)fPQ*Bd{mtH9%k zEAP^*L-8kmUc?ZRh_EglqPzjNiNucp_+mw|X)44V3jGDEIK+uNaSxNUaIzpBXdDV% zr8|CT$bIl;N3)`^ca3LSxAUWNP}qPr6{7W+AcRrmD%=I&T^waGXy4Vchle>$G9v(5 Q7_=V(ddL@#O$fmIze`HySO5S3 literal 0 HcmV?d00001 diff --git a/docs/userguide/advanced_data_comparison.md b/docs/userguide/advanced_data_comparison.md index c5e751526..6929b9845 100644 --- a/docs/userguide/advanced_data_comparison.md +++ b/docs/userguide/advanced_data_comparison.md @@ -6,7 +6,7 @@ utPLSQL expectations incorporates advanced data comparison options when comparin - object type - nested table and varray -Advanced data-comparison options are available for the [`equal`](expectations.md#equal) and [`include/ contain`](expectations.md#include) matcher. +Advanced data-comparison options are available for the [`equal`](expectations.md#equal) and [`include / contain`](expectations.md#include) matcher. ## Syntax @@ -27,7 +27,7 @@ Advanced data-comparison options are available for the [`equal`](expectations.md - `exclude(a_items varchar2)` - item or comma separated list of items to exclude - `include(a_items ut_varchar2_list)` - table of items to include - `exclude(a_items ut_varchar2_list)` - table of items to exclude - - `unordered` - perform compare on unordered set of data, return only missing or actual ***not supported for `include / contain`*** + - `unordered` - perform compare on unordered set of data, return only missing or actual, ***not supported for `include / contain`*** , as alternative `join_by` can be used - `join_by(a_columns varchar2)` - columns or comma separated list of columns to join two cursors by - `join_by(a_columns ut_varchar2_list)` - table of columns to join two cursors by diff --git a/docs/userguide/expectations.md b/docs/userguide/expectations.md index 66a352669..a2f31f4c1 100644 --- a/docs/userguide/expectations.md +++ b/docs/userguide/expectations.md @@ -437,15 +437,17 @@ To change the behavior of `NULL = NULL` comparison pass the `a_nulls_are_equal = This matcher supports only cursor comparison. It check if the give set contain all values from given subset. -Test using this matcher behaves similar to `equal` in respect that it succeeds only when the compared data-types are exactly the same. +when comparing data using `include / contain` matcher, the data-types of columns for compared cursors must be exactly the same. The matcher supports all advanced comparison options as `equal` e.g. include , exclude, join_by. -The matcher will be successful only when all of the values in expected results are part of actual set. +The matcher is successful when all of the values from expected results are included in actual data set. -In situation where the duplicate is present in expected set we would also expect matching number of occurrences in actual set for matcher to be success. +The matcher will cause a test to fail if any of expected values are not included in actual data set. -*Example 1* +![](D:\Oracle\Devwork\mygit\utPLSQL_pure_sql_cursor\docs\images\venn21.gif) + +*Example 1*. ```sql PROCEDURE ut_refcursors IS @@ -474,11 +476,56 @@ Will result in failure message Missing: 1 ``` +When duplicate rows are present in expected data set, actual data set must also include the same amount of duplicate. + +*Example 2.* -Similar negated `not_to_include`/ `not_to_contain` will be successful only when none of the values from expected set are part of actual e.g. -*Example 2.* +```sql +create or replace package ut_duplicate_test is + + --%suite(Sample Test Suite) + + --%test(Ref Cursor contain duplicates) + procedure ut_duplicate_include; + +end ut_duplicate_test; +/ + +create or replace package body ut_duplicate_test is + procedure ut_duplicate_include is + l_actual sys_refcursor; + l_expected sys_refcursor; + begin + open l_expected for select mod(level,2) as rn from dual connect by level < 5; + open l_actual for select mod(level,8) as rn from dual connect by level < 9; + ut.expect(l_actual).to_include(l_expected); + end; + +end ut_duplicate_test; +``` + +Will result in failure test message + +```sql + 1) ut_duplicate_include + Actual: refcursor [ count = 8 ] was expected to include: refcursor [ count = 4 ] + Diff: + Rows: [ 2 differences ] + Missing: 0 + Missing: 1 +``` + + + +The negated version of `include / contain` ( `not_to_include`/ `not_to_contain` ) is successful only when all values from expected set are not part of actual (they are disjoint and there is no overlap). + + + +![](D:\Oracle\Devwork\mygit\utPLSQL_pure_sql_cursor\docs\images\venn22.gif) + +*Example 3.* Set 1 is defined as [ A , B , C ] @@ -488,7 +535,7 @@ Set 1 is defined as [ A , B , C ] -*Example 2.* +*Example 4.* Set 1 is defined as [ A , B , C , D ] @@ -498,7 +545,7 @@ Set 1 is defined as [ A , B , C , D ] -*Example 3* +*Example 5. Set 1 is defined as [ A , B , C ] @@ -681,9 +728,9 @@ utPLSQL is capable of comparing compound data-types including: ### Notes on comparison of compound data - Compound data can contain elements of any data-type. This includes blob, clob, object type, nested table, varray or even a nested-cursor within a cursor. -- Nested table and varray types are compared as **ordered lists of elements**. If order of elements differ, expectation will fail. +- Attributes in nested table and array types are compared as **ordered lists of elements**. If order of attributes in nested table and array differ, expectation will fail. -- Cursors are compared as **unordered list of elements** by default. If order of elements is of importance the option has to be passed to enforce column order comparison `ordered_columns` e.g. +- Columns in cursors are compared as **unordered list of elements** by default. If order of columns in cursor is of importance the option has to be passed to enforce column order comparison `ordered_columns` e.g. ```sql procedure ut_refcursors1 is diff --git a/source/core/types/ut_cursor_info.tps b/source/core/types/ut_cursor_info.tps deleted file mode 100644 index 0577264f0..000000000 --- a/source/core/types/ut_cursor_info.tps +++ /dev/null @@ -1,22 +0,0 @@ -create or replace type ut_column_info as object ( - /* - utPLSQL - Version 3 - Copyright 2016 - 2018 utPLSQL Project - - Licensed under the Apache License, Version 2.0 (the "License"): - you may not use this file except in compliance with the License. - You may obtain a copy of the License at - - http://www.apache.org/licenses/LICENSE-2.0 - - Unless required by applicable law or agreed to in writing, software - distributed under the License is distributed on an "AS IS" BASIS, - WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. - See the License for the specific language governing permissions and - limitations under the License. - */ -column_name varchar2(100), -xml_valid_name varchar2(100), - -) - diff --git a/source/core/ut_utils.pkb b/source/core/ut_utils.pkb index 5e13e608c..dbe57f866 100644 --- a/source/core/ut_utils.pkb +++ b/source/core/ut_utils.pkb @@ -692,10 +692,5 @@ create or replace package body ut_utils is return l_result; end; - function serialize_data (a_data clob) return clob is - begin - return replace(a_data,chr(10)); - end; - end ut_utils; / diff --git a/source/core/ut_utils.pks b/source/core/ut_utils.pks index afaf50c28..5a0394813 100644 --- a/source/core/ut_utils.pks +++ b/source/core/ut_utils.pks @@ -354,8 +354,5 @@ create or replace package ut_utils authid definer is */ function replace_multiline_comments(a_source clob) return clob; - --TODO optimize clob replace to be more efficient as might not work replace on large clobs - function serialize_data (a_data clob) return clob; - end ut_utils; / diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 678da0ce9..7504a4d2b 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -20,7 +20,7 @@ create or replace package body ut_compound_data_helper is g_diff_count integer; g_filter_tab ut_varchar2_list; - type t_type_name_map is table of varchar2(100) index by binary_integer; + type t_type_name_map is table of varchar2(128) index by binary_integer; g_type_name_map t_type_name_map; g_anytype_name_map t_type_name_map; g_anytype_collection_name t_type_name_map; @@ -352,7 +352,7 @@ create or replace package body ut_compound_data_helper is begin dbms_lob.createtemporary(l_compare_sql, true); - gen_sql_pieces_out_of_cursor(a_other.cursor_details.cursor_info, a_join_by_list, + gen_sql_pieces_out_of_cursor(a_other.cursor_details.cursor_columns_info, a_join_by_list, l_xmltable_stmt, l_select_stmt, l_partition_stmt, l_equal_stmt, l_join_on_stmt, l_not_equal_stmt); diff --git a/source/expectations/data_values/ut_cursor_column.tps b/source/expectations/data_values/ut_cursor_column.tps index 6a4929d2d..dae1fc16d 100644 --- a/source/expectations/data_values/ut_cursor_column.tps +++ b/source/expectations/data_values/ut_cursor_column.tps @@ -1,16 +1,16 @@ create or replace type ut_cursor_column force authid current_user as object ( - parent_name varchar2(100), - access_path varchar2(500), + parent_name varchar2(4000), + access_path varchar2(4000), has_nested_col number(1,0), transformed_name varchar2(32), hierarchy_level number, column_position number, - xml_valid_name varchar2(100), - column_name varchar2(100), - column_type varchar2(100), - column_type_name varchar2(100), - column_schema varchar2(100), + xml_valid_name varchar2(128), + column_name varchar2(128), + column_type varchar2(128), + column_type_name varchar2(128), + column_schema varchar2(128), column_len integer, is_sql_diffable number(1, 0), is_collection number(1, 0), diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index 9f9f4bb52..446ea8942 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -5,14 +5,14 @@ create or replace type body ut_cursor_details as begin if self.is_column_order_enforced = 1 then select count(1) into l_diffs - from table(self.cursor_info) a full outer join table(a_other.cursor_info) e + from table(self.cursor_columns_info) a full outer join table(a_other.cursor_columns_info) e on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and REPLACE(a.column_type,'VARCHAR2','CHAR') = REPLACE(e.column_type,'VARCHAR2','CHAR') and a.column_position = e.column_position ) where a.column_name is null or e.column_name is null; else select count(1) into l_diffs - from table(self.cursor_info) a full outer join table(a_other.cursor_info) e + from table(self.cursor_columns_info) a full outer join table(a_other.cursor_columns_info) e on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and REPLACE(a.column_type,'VARCHAR2','CHAR') = REPLACE(e.column_type,'VARCHAR2','CHAR')) where a.column_name is null or e.column_name is null; @@ -155,8 +155,8 @@ create or replace type body ut_cursor_details as end if; l_is_collection := ut_compound_data_helper.is_collection(l_attribute_typecode); - self.cursor_info.extend; - self.cursor_info(cursor_info.last) := ut_cursor_column( l_aname, + self.cursor_columns_info.extend; + self.cursor_columns_info(cursor_columns_info.last) := ut_cursor_column( l_aname, l_schema_name, null, l_len, @@ -176,7 +176,7 @@ create or replace type body ut_cursor_details as constructor function ut_cursor_details(self in out nocopy ut_cursor_details) return self as result is begin - self.cursor_info := ut_cursor_column_tab(); + self.cursor_columns_info := ut_cursor_column_tab(); return; end; @@ -192,7 +192,7 @@ create or replace type body ut_cursor_details as l_hierarchy_level integer := 1; l_anytype anytype; begin - self.cursor_info := ut_cursor_column_tab(); + self.cursor_columns_info := ut_cursor_column_tab(); dbms_sql.describe_columns3(a_cursor_number, l_columns_count, l_columns_desc); @@ -205,8 +205,8 @@ create or replace type body ut_cursor_details as **/ for cur in 1 .. l_columns_count loop l_is_collection := ut_compound_data_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name); - self.cursor_info.extend; - self.cursor_info(cursor_info.last) := ut_cursor_column( l_columns_desc(cur).col_name, + self.cursor_columns_info.extend; + self.cursor_columns_info(cursor_columns_info.last) := ut_cursor_column( l_columns_desc(cur).col_name, l_columns_desc(cur).col_schema_name, l_columns_desc(cur).col_type_name, l_columns_desc(cur).col_max_len, diff --git a/source/expectations/data_values/ut_cursor_details.tps b/source/expectations/data_values/ut_cursor_details.tps index a64a6dd55..eb0f09f96 100644 --- a/source/expectations/data_values/ut_cursor_details.tps +++ b/source/expectations/data_values/ut_cursor_details.tps @@ -1,6 +1,6 @@ create or replace type ut_cursor_details force authid current_user as object ( - cursor_info ut_cursor_column_tab, + cursor_columns_info ut_cursor_column_tab, is_column_order_enforced number(1,0), order member function compare(a_other ut_cursor_details) return integer, member procedure get_anytype_members_info(a_anytype anytype, a_attribute_typecode out pls_integer, diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index c62163758..965bc4c54 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -102,7 +102,7 @@ create or replace type body ut_data_value_refcursor as overriding member function to_string return varchar2 is l_result clob; l_result_string varchar2(32767); - l_cursor_details ut_cursor_column_tab := self.cursor_details.cursor_info; + l_cursor_details ut_cursor_column_tab := self.cursor_details.cursor_columns_info; l_query varchar2(32767); l_column_info xmltype; @@ -204,13 +204,13 @@ create or replace type body ut_data_value_refcursor as end if; l_actual := treat(a_other as ut_data_value_refcursor); - l_act_cols := l_actual.cursor_details.cursor_info; - l_exp_cols := self.cursor_details.cursor_info; + l_act_cols := l_actual.cursor_details.cursor_columns_info; + l_exp_cols := self.cursor_details.cursor_columns_info; dbms_lob.createtemporary(l_result,true); --diff columns if not self.is_null and not l_actual.is_null then - l_column_diffs := ut_compound_data_helper.get_columns_diff(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info,l_column_order_enforce); + l_column_diffs := ut_compound_data_helper.get_columns_diff(self.cursor_details.cursor_columns_info,l_actual.cursor_details.cursor_columns_info,l_column_order_enforce); if l_column_diffs.count > 0 then ut_utils.append_to_clob(l_result,chr(10) || 'Columns:' || chr(10)); @@ -220,8 +220,8 @@ create or replace type body ut_data_value_refcursor as l_results(l_results.last) := get_col_diff_text(l_column_diffs(i)); end loop; ut_utils.append_to_clob(l_result, l_results); - l_act_cols := remove_incomparable_cols(l_actual.cursor_details.cursor_info,l_column_diffs); - l_exp_cols := remove_incomparable_cols(self.cursor_details.cursor_info,l_column_diffs); + l_act_cols := remove_incomparable_cols(l_actual.cursor_details.cursor_columns_info,l_column_diffs); + l_exp_cols := remove_incomparable_cols(self.cursor_details.cursor_columns_info,l_column_diffs); end if; --check for missing pk @@ -260,8 +260,8 @@ create or replace type body ut_data_value_refcursor as ut_utils.append_to_clob(l_result, get_missing_key_message(l_missing_pk(i))|| chr(10)); end loop; - if ut_compound_data_helper.contains_collection(self.cursor_details.cursor_info) > 0 - or ut_compound_data_helper.contains_collection(l_actual.cursor_details.cursor_info) > 0 then + if ut_compound_data_helper.contains_collection(self.cursor_details.cursor_columns_info) > 0 + or ut_compound_data_helper.contains_collection(l_actual.cursor_details.cursor_columns_info) > 0 then ut_utils.append_to_clob(l_result,' Please make sure that your join clause is not refferring to collection element'|| chr(10)); end if; @@ -286,7 +286,7 @@ create or replace type body ut_data_value_refcursor as l_actual := treat(a_other as ut_data_value_refcursor); if a_join_by_list.count > 0 then - l_pk_missing_tab := ut_compound_data_helper.get_missing_pk(self.cursor_details.cursor_info,l_actual.cursor_details.cursor_info,a_join_by_list); + l_pk_missing_tab := ut_compound_data_helper.get_missing_pk(self.cursor_details.cursor_columns_info,l_actual.cursor_details.cursor_columns_info,a_join_by_list); l_result := case when (l_pk_missing_tab.count > 0) then 1 else 0 end; end if; @@ -309,8 +309,8 @@ create or replace type body ut_data_value_refcursor as member function update_cursor_details (a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list,a_ordered_columns boolean := false) return ut_data_value_refcursor is l_result ut_data_value_refcursor := self; begin - if l_result.cursor_details.cursor_info is not null then - l_result.cursor_details.cursor_info := ut_compound_data_helper.inc_exc_columns_from_cursor(l_result.cursor_details.cursor_info,a_exclude_xpath,a_include_xpath); + if l_result.cursor_details.cursor_columns_info is not null then + l_result.cursor_details.cursor_columns_info := ut_compound_data_helper.inc_exc_columns_from_cursor(l_result.cursor_details.cursor_columns_info,a_exclude_xpath,a_include_xpath); l_result.cursor_details.ordered_columns(a_ordered_columns); end if; return l_result; From 3ff1e2703f9e4647ce2979ee7fa543fbe722ff32 Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Sun, 9 Dec 2018 14:59:49 +0000 Subject: [PATCH 72/83] Updated paths to venn diagram images --- docs/userguide/expectations.md | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/docs/userguide/expectations.md b/docs/userguide/expectations.md index a2f31f4c1..5ba07e48f 100644 --- a/docs/userguide/expectations.md +++ b/docs/userguide/expectations.md @@ -445,7 +445,7 @@ The matcher is successful when all of the values from expected results are inclu The matcher will cause a test to fail if any of expected values are not included in actual data set. -![](D:\Oracle\Devwork\mygit\utPLSQL_pure_sql_cursor\docs\images\venn21.gif) +![included_set](../images/venn21.gif) *Example 1*. @@ -523,7 +523,7 @@ The negated version of `include / contain` ( `not_to_include`/ `not_to_contain` -![](D:\Oracle\Devwork\mygit\utPLSQL_pure_sql_cursor\docs\images\venn22.gif) +![not_overlapping_set](../images/venn22.gif) *Example 3.* From 69da762f1dc35735085f76fd3c4d7b86485d24e4 Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Sun, 9 Dec 2018 15:07:46 +0000 Subject: [PATCH 73/83] Fixed formatting of examples. --- docs/userguide/expectations.md | 338 ++++++++++++++++----------------- 1 file changed, 159 insertions(+), 179 deletions(-) diff --git a/docs/userguide/expectations.md b/docs/userguide/expectations.md index 5ba07e48f..04a5fef18 100644 --- a/docs/userguide/expectations.md +++ b/docs/userguide/expectations.md @@ -112,7 +112,7 @@ create or replace package body test_divide is procedure divides_numbers is begin - ut3.ut.expect(divide(6,2)).to_equal(3); + ut.expect(divide(6,2)).to_equal(3); end; procedure raises_divisor_exception is @@ -124,7 +124,7 @@ create or replace package body test_divide is end; / -exec ut3.ut.run('test_divide'); +exec ut.run('test_divide'); ``` For details see documentation of the [`--%throws` annotation.](annotations.md#throws-annotation) @@ -364,68 +364,68 @@ end; create or replace package test_animals_getter is - --%suite(Animals getter tests) - - --%test(get_animal - returns a dog) - procedure test_variant_1_get_animal; - --%test(get_animal - returns a dog) - procedure test_variant_2_get_animal; - --%test(get_animal - returns a dog) - procedure test_variant_3_get_animal; - --%test(get_animal - returns a dog) - procedure test_variant_4_get_animal; - --%test(get_animal - returns a dog) - procedure test_variant_5_get_animal; + --%suite(Animals getter tests) + + --%test(get_animal - returns a dog) + procedure test_variant_1_get_animal; + --%test(get_animal - returns a dog) + procedure test_variant_2_get_animal; + --%test(get_animal - returns a dog) + procedure test_variant_3_get_animal; + --%test(get_animal - returns a dog) + procedure test_variant_4_get_animal; + --%test(get_animal - returns a dog) + procedure test_variant_5_get_animal; end; / create or replace package body test_animals_getter is - --The below tests perform exactly the same check. - --They use different syntax to achieve the goal. - procedure test_variant_1_get_animal is - l_actual varchar2(100) := 'a dog'; - l_expected varchar2(100); - begin - --Arrange - l_actual := 'a dog'; - --Act - l_expected := get_animal(); - --Assert - ut.expect( l_actual ).to_equal( l_expected ); - end; + --The below tests perform exactly the same check. + --They use different syntax to achieve the goal. + procedure test_variant_1_get_animal is + l_actual varchar2(100) := 'a dog'; + l_expected varchar2(100); + begin + --Arrange + l_actual := 'a dog'; + --Act + l_expected := get_animal(); + --Assert + ut.expect( l_actual ).to_equal( l_expected ); + end; - procedure test_variant_2_get_animal is - l_expected varchar2(100); - begin - --Act - l_expected := get_animal(); - --Assert - ut.expect( l_expected ).to_equal( 'a dog' ); - end; + procedure test_variant_2_get_animal is + l_expected varchar2(100); + begin + --Act + l_expected := get_animal(); + --Assert + ut.expect( l_expected ).to_equal( 'a dog' ); + end; - procedure test_variant_3_get_animal is - begin - --Act / Assert - ut.expect( get_animal() ).to_equal( 'a dog' ); - end; + procedure test_variant_3_get_animal is + begin + --Act / Assert + ut.expect( get_animal() ).to_equal( 'a dog' ); + end; - procedure test_variant_4_get_animal is - begin - --Act / Assert - ut.expect( get_animal() ).to_equal( 'a dog', a_nulls_are_equal => true ); - end; + procedure test_variant_4_get_animal is + begin + --Act / Assert + ut.expect( get_animal() ).to_equal( 'a dog', a_nulls_are_equal => true ); + end; - procedure test_variant_5_get_animal is - begin - --Act / Assert - ut.expect( get_animal() ).to_( equal( 'a dog' ) ); - end; + procedure test_variant_5_get_animal is + begin + --Act / Assert + ut.expect( get_animal() ).to_( equal( 'a dog' ) ); + end; - procedure test_variant_6_get_animal is - begin - --Act / Assert - ut.expect( get_animal() ).to_( equal( 'a dog', a_nulls_are_equal => true ) ); - end; + procedure test_variant_6_get_animal is + begin + --Act / Assert + ut.expect( get_animal() ).to_( equal( 'a dog', a_nulls_are_equal => true ) ); + end; end; ``` @@ -450,7 +450,7 @@ The matcher will cause a test to fail if any of expected values are not included *Example 1*. ```sql - PROCEDURE ut_refcursors IS + procedure ut_refcursors is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; begin @@ -461,7 +461,7 @@ The matcher will cause a test to fail if any of expected values are not included --Act ut.expect(l_actual).to_include(l_expected); - END; + end; ``` Will result in failure message @@ -495,8 +495,8 @@ end ut_duplicate_test; create or replace package body ut_duplicate_test is procedure ut_duplicate_include is - l_actual sys_refcursor; - l_expected sys_refcursor; + l_actual sys_refcursor; + l_expected sys_refcursor; begin open l_expected for select mod(level,2) as rn from dual connect by level < 5; open l_actual for select mod(level,8) as rn from dual connect by level < 9; @@ -559,117 +559,100 @@ Example usage ```sql create or replace package example_include is - --%suite(Include test) + --%suite(Include test) + + --%test( Cursor include data from another cursor) + procedure cursor_to_include; + + --%test( Cursor include data from another cursor) + procedure cursor_not_to_include; + + --%test( Cursor fail include) + procedure cursor_fail_include; - --%test( Cursor include data from another cursor) - procedure cursor_to_include; - - --%test( Cursor include data from another cursor) - procedure cursor_not_to_include; - - --%test( Cursor fail include) - procedure cursor_fail_include; - - --%test( Cursor fail not include) - procedure cursor_fail_not_include; + --%test( Cursor fail not include) + procedure cursor_fail_not_include; end; / create or replace package body example_include is - procedure cursor_to_include is - l_actual SYS_REFCURSOR; - l_expected SYS_REFCURSOR; - begin - --Arrange - open l_actual for - select 'a' as name from dual - union all - select 'b' as name from dual - union all - select 'c' as name from dual - union all - select 'd' as name from dual; - - open l_expected for - select 'a' as name from dual - union all - select 'b' as name from dual - union all - select 'c' as name from dual; - - --Act - ut3.ut.expect(l_actual).to_include(l_expected); - end; - - procedure cursor_not_to_include is - l_actual SYS_REFCURSOR; - l_expected SYS_REFCURSOR; - begin - --Arrange - open l_actual for - select 'a' as name from dual - union all - select 'b' as name from dual - union all - select 'c' as name from dual; - - open l_expected for - select 'd' as name from dual - union all - select 'e' as name from dual - union all - select 'f' as name from dual; - - --Act - ut3.ut.expect(l_actual).not_to_include(l_expected); - end; + procedure cursor_to_include is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for + select 'a' as name from dual union all + select 'b' as name from dual union all + select 'c' as name from dual union all + select 'd' as name from dual; - procedure cursor_fail_include is - l_actual SYS_REFCURSOR; - l_expected SYS_REFCURSOR; - begin - --Arrange - open l_actual for - select 'a' as name from dual - union all - select 'b' as name from dual - union all - select 'c' as name from dual; - - open l_expected for - select 'a' as name from dual - union all - select 'd' as name from dual - union all - select 'e' as name from dual; - - --Act - ut3.ut.expect(l_actual).to_include(l_expected); - end; - - procedure cursor_fail_not_include is - l_actual SYS_REFCURSOR; - l_expected SYS_REFCURSOR; - begin - --Arrange - open l_actual for - select 'a' as name from dual - union all - select 'b' as name from dual - union all - select 'c' as name from dual; - - open l_expected for - select 'a' as name from dual - union all - select 'd' as name from dual - union all - select 'e' as name from dual; - - --Act - ut3.ut.expect(l_actual).not_to_include(l_expected); - end; + open l_expected for + select 'a' as name from dual union all + select 'b' as name from dual union all + select 'c' as name from dual; + + --Act + ut.expect(l_actual).to_include(l_expected); + end; + + procedure cursor_not_to_include is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for + select 'a' as name from dual union all + select 'b' as name from dual union all + select 'c' as name from dual; + + open l_expected for + select 'd' as name from dual union all + select 'e' as name from dual union all + select 'f' as name from dual; + + --Act + ut.expect(l_actual).not_to_include(l_expected); + end; + + procedure cursor_fail_include is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for + select 'a' as name from dual union all + select 'b' as name from dual union all + select 'c' as name from dual; + + open l_expected for + select 'a' as name from dual union all + select 'd' as name from dual union all + select 'e' as name from dual; + + --Act + ut.expect(l_actual).to_include(l_expected); + end; + + procedure cursor_fail_not_include is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for + select 'a' as name from dual union all + select 'b' as name from dual union all + select 'c' as name from dual; + + open l_expected for + select 'a' as name from dual union all + select 'd' as name from dual union all + select 'e' as name from dual; + + --Act + ut.expect(l_actual).not_to_include(l_expected); + end; end; / ``` @@ -693,7 +676,7 @@ Failures: Rows: [ 2 differences ] Missing: d Missing: e - at "UT3.EXAMPLE_INCLUDE.CURSOR_FAIL_INCLUDE", line 71 ut3.ut.expect(l_actual).to_include(l_expected); + at "UT3.EXAMPLE_INCLUDE.CURSOR_FAIL_INCLUDE", line 71 ut.expect(l_actual).to_include(l_expected); 2) cursor_fail_not_include @@ -713,7 +696,7 @@ Failures: a d e - at "UT3.EXAMPLE_INCLUDE.CURSOR_FAIL_NOT_INCLUDE", line 94 ut3.ut.expect(l_actual).not_to_include(l_expected); + at "UT3.EXAMPLE_INCLUDE.CURSOR_FAIL_NOT_INCLUDE", line 94 ut.expect(l_actual).not_to_include(l_expected); ``` @@ -734,15 +717,15 @@ utPLSQL is capable of comparing compound data-types including: ```sql procedure ut_refcursors1 is - l_actual sys_refcursor; - l_expected sys_refcursor; - l_expected_message varchar2(32767); - l_actual_message varchar2(32767); + l_actual sys_refcursor; + l_expected sys_refcursor; + l_expected_message varchar2(32767); + l_actual_message varchar2(32767); begin - open l_actual for select 1 user_id,'s' a_col,'test' username from dual; - open l_expected for select 'test' username,'s' a_col,1 user_id from dual; - --Act - ut3.ut.expect(l_actual).to_equal(l_expected).join_by('USER_ID').ordered_columns; + open l_actual for select 1 user_id,'s' a_col,'test' username from dual; + open l_expected for select 'test' username,'s' a_col,1 user_id from dual; + --Act + ut.expect(l_actual).to_equal(l_expected).join_by('USER_ID').ordered_columns; end; ``` @@ -1069,9 +1052,9 @@ Example below illustrates usage of `cast` operator to assure appropriate precisi ```sql drop table timestamps; create table timestamps ( - ts3 timestamp (3), - ts6 timestamp (6), - ts9 timestamp (9) + ts3 timestamp (3), + ts6 timestamp (6), + ts9 timestamp (9) ); create or replace package timestamps_api is @@ -1206,6 +1189,3 @@ The matrix below illustrates the data types supported by different matchers. | **be_empty** | X | | X | | | | | | | | | X | X | | | **have_count** | | | | | | | | | | | | X | X | | -​ - - From 8697cea7ed2c359d14d4176892f68eda097563e4 Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Sun, 9 Dec 2018 18:09:36 +0000 Subject: [PATCH 74/83] Added missing synonyms for new matchers `contain / include` Fixed public synonyms - they are now pointing to private ut3 synonyms for matchers. --- source/api/contain.syn | 1 + source/api/include.syn | 1 + .../create_synonyms_and_grants_for_public.sql | 30 +++++++++++-------- source/create_user_synonyms.sql | 2 ++ source/install.sql | 2 ++ source/uninstall_objects.sql | 4 +++ .../expectations/test_expectations_cursor.pkb | 4 +-- 7 files changed, 29 insertions(+), 15 deletions(-) create mode 100644 source/api/contain.syn create mode 100644 source/api/include.syn diff --git a/source/api/contain.syn b/source/api/contain.syn new file mode 100644 index 000000000..34609ef8b --- /dev/null +++ b/source/api/contain.syn @@ -0,0 +1 @@ +create synonym contain for ut_include; diff --git a/source/api/include.syn b/source/api/include.syn new file mode 100644 index 000000000..855700e1e --- /dev/null +++ b/source/api/include.syn @@ -0,0 +1 @@ +create synonym include for ut_include; diff --git a/source/create_synonyms_and_grants_for_public.sql b/source/create_synonyms_and_grants_for_public.sql index b8daca313..b745449bf 100644 --- a/source/create_synonyms_and_grants_for_public.sql +++ b/source/create_synonyms_and_grants_for_public.sql @@ -112,20 +112,24 @@ prompt Creating synonyms for UTPLSQL objects in &&ut3_owner schema to PUBLIC create public synonym ut_expectation for &&ut3_owner..ut_expectation; create public synonym ut_expectation_compound for &&ut3_owner..ut_expectation_compound; -create public synonym be_between for &&ut3_owner..ut_be_between; -create public synonym be_empty for &&ut3_owner..ut_be_empty; -create public synonym be_false for &&ut3_owner..ut_be_false; -create public synonym be_greater_or_equal for &&ut3_owner..ut_be_greater_or_equal; -create public synonym be_greater_than for &&ut3_owner..ut_be_greater_than; -create public synonym be_less_or_equal for &&ut3_owner..ut_be_less_or_equal; -create public synonym be_less_than for &&ut3_owner..ut_be_less_than; -create public synonym be_like for &&ut3_owner..ut_be_like; -create public synonym be_not_null for &&ut3_owner..ut_be_not_null; -create public synonym be_null for &&ut3_owner..ut_be_null; -create public synonym be_true for &&ut3_owner..ut_be_true; -create public synonym equal for &&ut3_owner..ut_equal; + +create public synonym be_between for &&ut3_owner..be_between; +create public synonym be_empty for &&ut3_owner..be_empty; +create public synonym be_false for &&ut3_owner..be_false; +create public synonym be_greater_or_equal for &&ut3_owner..be_greater_or_equal; +create public synonym be_greater_than for &&ut3_owner..be_greater_than; +create public synonym be_less_or_equal for &&ut3_owner..be_less_or_equal; +create public synonym be_less_than for &&ut3_owner..be_less_than; +create public synonym be_like for &&ut3_owner..be_like; +create public synonym be_not_null for &&ut3_owner..be_not_null; +create public synonym be_null for &&ut3_owner..be_null; +create public synonym be_true for &&ut3_owner..be_true; +create public synonym contain for &&ut3_owner..include; +create public synonym equal for &&ut3_owner..equal; create public synonym have_count for &&ut3_owner..have_count; -create public synonym match for &&ut3_owner..ut_match; +create public synonym include for &&ut3_owner..include; +create public synonym match for &&ut3_owner..match; + create public synonym ut for &&ut3_owner..ut; create public synonym ut_runner for &&ut3_owner..ut_runner; create public synonym ut_teamcity_reporter for &&ut3_owner..ut_teamcity_reporter; diff --git a/source/create_user_synonyms.sql b/source/create_user_synonyms.sql index 9a087f61a..3c75c590b 100644 --- a/source/create_user_synonyms.sql +++ b/source/create_user_synonyms.sql @@ -55,6 +55,7 @@ prompt Creating synonyms for UTPLSQL objects in &&ut3_owner schema to user &&ut3 create or replace synonym &ut3_user..ut_expectation for &&ut3_owner..ut_expectation; create or replace synonym &ut3_user..ut_expectation_compound for &&ut3_owner..ut_expectation_compound; + create or replace synonym &ut3_user..be_between for &&ut3_owner..be_between; create or replace synonym &ut3_user..be_empty for &&ut3_owner..be_empty; create or replace synonym &ut3_user..be_false for &&ut3_owner..be_false; @@ -69,6 +70,7 @@ create or replace synonym &ut3_user..be_true for &&ut3_owner..be_true; create or replace synonym &ut3_user..equal for &&ut3_owner..equal; create or replace synonym &ut3_user..have_count for &&ut3_owner..have_count; create or replace synonym &ut3_user..match for &&ut3_owner..match; + create or replace synonym &ut3_user..ut for &&ut3_owner..ut; create or replace synonym &ut3_user..ut_runner for &&ut3_owner..ut_runner; create or replace synonym &ut3_user..ut_teamcity_reporter for &&ut3_owner..ut_teamcity_reporter; diff --git a/source/install.sql b/source/install.sql index 59283a5de..c029baaef 100644 --- a/source/install.sql +++ b/source/install.sql @@ -312,6 +312,8 @@ prompt Installing DBMSPLSQL Tables objects into &&ut3_owner schema @@install_component.sql 'api/equal.syn' @@install_component.sql 'api/have_count.syn' @@install_component.sql 'api/match.syn' +@@install_component.sql 'api/contain.syn' +@@install_component.sql 'api/include.syn' set linesize 200 set define on diff --git a/source/uninstall_objects.sql b/source/uninstall_objects.sql index 0475e347d..a268acc8a 100644 --- a/source/uninstall_objects.sql +++ b/source/uninstall_objects.sql @@ -5,6 +5,10 @@ drop synonym have_count; drop synonym match; +drop synonym include; + +drop synonym contain; + drop synonym be_false; drop synonym be_empty; diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index d38dfb402..f47a72339 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -2107,7 +2107,7 @@ Diff:% and rownum < 20; --Act - ut3.ut.expect(l_actual).to_include(l_expected); + ut3.ut.expect(l_actual).to_( ut3.include(l_expected) ); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; @@ -2151,7 +2151,7 @@ Diff:% and rownum < 20; --Act - ut3.ut.expect(l_actual).to_contain(l_expected); + ut3.ut.expect(l_actual).to_( ut3.contain(l_expected) ); --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; From 1645445adb843704e1947e8bfd1fea48637dcb20 Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Sun, 9 Dec 2018 18:40:35 +0000 Subject: [PATCH 75/83] Formatting fixes. --- .../data_values/ut_compound_data_value.tpb | 69 +++++++++++-------- .../data_values/ut_data_value_refcursor.tpb | 16 ++--- 2 files changed, 47 insertions(+), 38 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index a8323eecd..f5d3968cc 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -69,7 +69,10 @@ create or replace type body ut_compound_data_value as return l_result_string; end; - overriding member function diff( a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, a_join_by_xpath varchar2, a_unordered boolean := false ) return varchar2 is + overriding member function diff( + a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_join_by_xpath varchar2, a_unordered boolean := false + ) return varchar2 is l_result clob; l_result_string varchar2(32767); begin @@ -80,8 +83,10 @@ create or replace type body ut_compound_data_value as end; -- TODO : Rework to exclude xpath - member function get_data_diff(a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, - a_join_by_xpath varchar2, a_unordered boolean) return clob is + member function get_data_diff( + a_other ut_data_value, a_exclude_xpath varchar2, a_include_xpath varchar2, + a_join_by_xpath varchar2, a_unordered boolean + ) return clob is c_max_rows integer := ut_utils.gc_diff_max_rows; l_result clob; l_results ut_utils.t_clob_tab := ut_utils.t_clob_tab(); @@ -191,8 +196,10 @@ create or replace type body ut_compound_data_value as return l_result; end; - member function compare_implementation(a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean, - a_is_negated boolean, a_join_by_list ut_varchar2_list:=ut_varchar2_list()) return integer is + member function compare_implementation( + a_other ut_data_value, a_unordered boolean, a_inclusion_compare boolean, + a_is_negated boolean, a_join_by_list ut_varchar2_list := ut_varchar2_list() + ) return integer is l_diff_id ut_compound_data_helper.t_hash; l_other ut_compound_data_value; @@ -205,33 +212,35 @@ create or replace type body ut_compound_data_value as l_sql_rowcount integer :=0; begin - l_other := treat(a_other as ut_compound_data_value); - l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - - open l_loop_curs for ut_compound_data_helper.gen_compare_sql(a_inclusion_compare, a_is_negated, a_unordered, - treat(a_other as ut_data_value_refcursor), a_join_by_list ) using self.data_id,l_other.data_id; - loop - fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; - exit when l_diff_tab.count = 0; - if (ut_utils.gc_diff_max_rows > l_sql_rowcount ) then - ut_compound_data_helper.insert_diffs_result(l_diff_tab,l_diff_id); - end if; - l_sql_rowcount := l_sql_rowcount + l_diff_tab.count; - if (ut_utils.gc_diff_max_rows <= l_sql_rowcount and l_max_rows != ut_utils.gc_bc_fetch_limit ) then - l_max_rows := ut_utils.gc_bc_fetch_limit; - end if; - end loop; - - ut_compound_data_helper.set_rows_diff(l_sql_rowcount); - --result is OK only if both are same - if l_sql_rowcount = 0 and ( self.elements_count = l_other.elements_count or a_inclusion_compare )then - l_result := 0; - else - l_result := 1; - end if; + l_other := treat(a_other as ut_compound_data_value); + l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); + + open l_loop_curs for + ut_compound_data_helper.gen_compare_sql( + a_inclusion_compare, a_is_negated, a_unordered, + treat(a_other as ut_data_value_refcursor), a_join_by_list + ) using self.data_id,l_other.data_id; + loop + fetch l_loop_curs bulk collect into l_diff_tab limit l_max_rows; + exit when l_diff_tab.count = 0; + if (ut_utils.gc_diff_max_rows > l_sql_rowcount ) then + ut_compound_data_helper.insert_diffs_result(l_diff_tab,l_diff_id); + end if; + l_sql_rowcount := l_sql_rowcount + l_diff_tab.count; + if (ut_utils.gc_diff_max_rows <= l_sql_rowcount and l_max_rows != ut_utils.gc_bc_fetch_limit ) then + l_max_rows := ut_utils.gc_bc_fetch_limit; + end if; + end loop; - return l_result; + ut_compound_data_helper.set_rows_diff(l_sql_rowcount); + --result is OK only if both are same + if l_sql_rowcount = 0 and ( self.elements_count = l_other.elements_count or a_inclusion_compare ) then + l_result := 0; + else + l_result := 1; + end if; + return l_result; end; end; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 965bc4c54..10be342ea 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -25,10 +25,10 @@ create or replace type body ut_data_value_refcursor as member procedure extract_cursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) is c_bulk_rows constant integer := 10000; l_cursor sys_refcursor := a_value; - l_ctx number; - l_xml xmltype; - l_ut_owner varchar2(250) := ut_utils.ut_owner; - l_set_id integer := 0; + l_ctx number; + l_xml xmltype; + l_ut_owner varchar2(250) := ut_utils.ut_owner; + l_set_id integer := 0; begin -- We use DBMS_XMLGEN in order to: -- 1) be able to process data in bulks (set of rows) @@ -67,8 +67,8 @@ create or replace type body ut_data_value_refcursor as end; member procedure init(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) is - l_cursor sys_refcursor := a_value; - cursor_not_open exception; + l_cursor sys_refcursor := a_value; + cursor_not_open exception; l_cursor_number number; begin self.is_data_null := ut_utils.boolean_to_int(a_value is null); @@ -80,13 +80,13 @@ create or replace type body ut_data_value_refcursor as if l_cursor is not null then if l_cursor%isopen then --Get some more info regarding cursor, including if it containts collection columns and what is their name - self.elements_count := 0; + self.elements_count := 0; extract_cursor(l_cursor); l_cursor_number := dbms_sql.to_cursor_number(l_cursor); self.cursor_details := ut_cursor_details(l_cursor_number); dbms_sql.close_cursor(l_cursor_number); elsif not l_cursor%isopen then - raise cursor_not_open; + raise cursor_not_open; end if; end if; exception From 62c12cd5ed72d64d4f3457e1d278342f910b219b Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Sun, 9 Dec 2018 18:44:09 +0000 Subject: [PATCH 76/83] Removed unused variables. --- source/expectations/data_values/ut_compound_data_value.tpb | 6 +----- 1 file changed, 1 insertion(+), 5 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index f5d3968cc..860bc2ae3 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -43,7 +43,6 @@ create or replace type body ut_compound_data_value as overriding member function to_string return varchar2 is l_results ut_utils.t_clob_tab; - c_max_rows constant integer := 20; l_result clob; l_result_string varchar2(32767); begin @@ -91,14 +90,11 @@ create or replace type body ut_compound_data_value as l_result clob; l_results ut_utils.t_clob_tab := ut_utils.t_clob_tab(); l_message varchar2(32767); - l_ut_owner varchar2(250) := ut_utils.ut_owner; l_diff_row_count integer; l_actual ut_compound_data_value; l_diff_id ut_compound_data_helper.t_hash; l_row_diffs ut_compound_data_helper.tt_row_diffs; - l_compare_type varchar2(10); - l_self ut_compound_data_value; - + function get_diff_message (a_row_diff ut_compound_data_helper.t_row_diffs,a_is_unordered boolean) return varchar2 is begin return ' Row No. '||a_row_diff.rn||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row; From ca9f8ebfaeaaa687479f4cf1b26fc70ff931ea6a Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Sun, 9 Dec 2018 19:20:00 +0000 Subject: [PATCH 77/83] Formatting fixes. --- .../data_values/ut_compound_data_helper.pkb | 16 +- .../data_values/ut_cursor_column.tpb | 103 ++-- .../data_values/ut_cursor_details.tpb | 488 +++++++++--------- source/expectations/matchers/ut_include.tpb | 15 +- 4 files changed, 322 insertions(+), 300 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 7504a4d2b..0e3ffdcfa 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -780,7 +780,12 @@ create or replace package body ut_compound_data_helper is end if; end; - function is_collection (a_owner varchar2,a_type_name varchar2, a_anytype_code in integer :=null) return boolean is + function is_collection (a_anytype_code in integer) return boolean is + begin + return a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection); + end; + + function is_collection (a_owner varchar2, a_type_name varchar2, a_anytype_code in integer :=null) return boolean is l_type_view varchar2(200) := ut_metadata.get_dba_view('dba_types'); l_typecode varchar2(100); begin @@ -791,7 +796,7 @@ create or replace package body ut_compound_data_helper is return l_typecode = 'COLLECTION'; else - return a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection); + return is_collection(a_anytype_code); end if; exception @@ -799,13 +804,6 @@ create or replace package body ut_compound_data_helper is return false; end; - function is_collection (a_anytype_code in integer) return boolean is - l_type_view varchar2(200) := ut_metadata.get_dba_view('dba_types'); - l_typecode varchar2(100); - begin - return a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection); - end; - function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is begin return case when a_dbms_sql_desc then g_type_name_map(a_type_code) else g_anytype_name_map(a_type_code) end; diff --git a/source/expectations/data_values/ut_cursor_column.tpb b/source/expectations/data_values/ut_cursor_column.tpb index 52be9a3d4..a956164f5 100644 --- a/source/expectations/data_values/ut_cursor_column.tpb +++ b/source/expectations/data_values/ut_cursor_column.tpb @@ -1,50 +1,53 @@ -create or replace type body ut_cursor_column as - - member procedure init(self in out nocopy ut_cursor_column, - a_col_name varchar2, a_col_schema_name varchar2, - a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, - a_col_position integer, a_col_type varchar2, a_collection integer,a_access_path in varchar2) is - begin - self.parent_name := a_parent_name; --Name of the parent if its nested - self.hierarchy_level := a_hierarchy_level; --Hierarchy level - self.column_position := a_col_position; --Position of the column in cursor/ type - self.column_len := a_col_max_len; --length of column - self.column_name := TRIM( BOTH '''' FROM a_col_name); --name of the column - self.column_type_name := a_col_type_name; --type name e.g. test_dummy_object or varchar2 - self.access_path := case when a_access_path is null then - self.column_name - else - a_access_path||'/'||self.column_name - end; --Access path used for incldue exclude eg/ TEST_DUMMY_OBJECT/VARCHAR2 - self.xml_valid_name := '"'||self.column_name||'"'; --User friendly column name - self.transformed_name := case when self.parent_name is null then - self.xml_valid_name - else - '"'||ut_compound_data_helper.get_fixed_size_hash(self.parent_name||self.column_name)||'"' - end; --when is nestd we need to hash name to make sure we dont exceed 30 char - self.column_type := a_col_type; --column type e.g. user_defined , varchar2 - self.column_schema := a_col_schema_name; -- schema name - self.is_sql_diffable := case when lower(self.column_type) = 'user_defined_type' then - 0 - else - ut_utils.boolean_to_int(ut_compound_data_helper.is_sql_compare_allowed(self.column_type)) - end; --can we directly compare or do we need to hash value - self.is_collection := a_collection; - self.has_nested_col := case when lower(self.column_type) = 'user_defined_type' and self.is_collection = 0 then 1 else 0 end; - end; - - constructor function ut_cursor_column( self in out nocopy ut_cursor_column, - a_col_name varchar2, a_col_schema_name varchar2, - a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, - a_col_position integer, a_col_type in varchar2, a_collection integer,a_access_path in varchar2) return self as result is - begin - init(a_col_name, a_col_schema_name, a_col_type_name, a_col_max_len, a_parent_name,a_hierarchy_level, a_col_position, a_col_type, a_collection,a_access_path); - return; - end; - - constructor function ut_cursor_column( self in out nocopy ut_cursor_column) return self as result is - begin - return; - end; -end; -/ +create or replace type body ut_cursor_column as + + member procedure init( + self in out nocopy ut_cursor_column, + a_col_name varchar2, a_col_schema_name varchar2, + a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_position integer, a_col_type varchar2, a_collection integer,a_access_path in varchar2 + ) is + begin + self.parent_name := a_parent_name; --Name of the parent if its nested + self.hierarchy_level := a_hierarchy_level; --Hierarchy level + self.column_position := a_col_position; --Position of the column in cursor/ type + self.column_len := a_col_max_len; --length of column + self.column_name := TRIM( BOTH '''' FROM a_col_name); --name of the column + self.column_type_name := a_col_type_name; --type name e.g. test_dummy_object or varchar2 + self.access_path := case when a_access_path is null then + self.column_name + else + a_access_path||'/'||self.column_name + end; --Access path used for incldue exclude eg/ TEST_DUMMY_OBJECT/VARCHAR2 + self.xml_valid_name := '"'||self.column_name||'"'; --User friendly column name + self.transformed_name := case when self.parent_name is null then + self.xml_valid_name + else + '"'||ut_compound_data_helper.get_fixed_size_hash(self.parent_name||self.column_name)||'"' + end; --when is nestd we need to hash name to make sure we dont exceed 30 char + self.column_type := a_col_type; --column type e.g. user_defined , varchar2 + self.column_schema := a_col_schema_name; -- schema name + self.is_sql_diffable := case when lower(self.column_type) = 'user_defined_type' then + 0 + else + ut_utils.boolean_to_int(ut_compound_data_helper.is_sql_compare_allowed(self.column_type)) + end; --can we directly compare or do we need to hash value + self.is_collection := a_collection; + self.has_nested_col := case when lower(self.column_type) = 'user_defined_type' and self.is_collection = 0 then 1 else 0 end; + end; + + constructor function ut_cursor_column( self in out nocopy ut_cursor_column, + a_col_name varchar2, a_col_schema_name varchar2, + a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_position integer, a_col_type in varchar2, a_collection integer,a_access_path in varchar2 + ) return self as result is + begin + init(a_col_name, a_col_schema_name, a_col_type_name, a_col_max_len, a_parent_name,a_hierarchy_level, a_col_position, a_col_type, a_collection,a_access_path); + return; + end; + + constructor function ut_cursor_column( self in out nocopy ut_cursor_column) return self as result is + begin + return; + end; +end; +/ diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index 446ea8942..beb60e44d 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -1,238 +1,250 @@ -create or replace type body ut_cursor_details as - - order member function compare(a_other ut_cursor_details) return integer is - l_diffs integer; - begin - if self.is_column_order_enforced = 1 then - select count(1) into l_diffs - from table(self.cursor_columns_info) a full outer join table(a_other.cursor_columns_info) e - on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and - REPLACE(a.column_type,'VARCHAR2','CHAR') = REPLACE(e.column_type,'VARCHAR2','CHAR') - and a.column_position = e.column_position ) - where a.column_name is null or e.column_name is null; - else - select count(1) into l_diffs - from table(self.cursor_columns_info) a full outer join table(a_other.cursor_columns_info) e - on ( decode(a.parent_name,e.parent_name,1,0)= 1 and a.column_name = e.column_name and - REPLACE(a.column_type,'VARCHAR2','CHAR') = REPLACE(e.column_type,'VARCHAR2','CHAR')) - where a.column_name is null or e.column_name is null; - end if; - return l_diffs; - end; - - member procedure get_anytype_members_info(a_anytype anytype, a_attribute_typecode out pls_integer, - a_schema_name out varchar2, a_type_name out varchar2, a_len out pls_integer,a_elements_count out pls_integer) is - l_version varchar2(32767); - l_prec pls_integer; - l_scale pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - begin - a_attribute_typecode := a_anytype.getinfo(prec => l_prec, - scale => l_scale, - len => a_len, - csid => l_csid, - csfrm => l_csfrm, - schema_name => a_schema_name, - type_name => a_type_name, - version => l_version, - numelems => a_elements_count); - end; - - member procedure getattreleminfo(a_anytype anytype,a_pos pls_integer, a_attribute_typecode out pls_integer, - a_type_name out varchar2, a_len out pls_integer, a_attr_elt_type out anytype) is - l_version varchar2(32767); - l_prec pls_integer; - l_scale pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - l_attr_elt_type anytype; - begin - a_attribute_typecode := a_anytype.getattreleminfo(pos => a_pos, --First attribute - prec => l_prec, - scale => l_scale, - len => a_len, - csid => l_csid, - csfrm => l_csfrm, - attr_elt_type => l_attr_elt_type, - aname => a_type_name); - end; - - member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) - return anytype is - l_anydata anydata; - l_anytype anytype; - l_typecode pls_integer; - begin - execute immediate 'declare - l_v ' || a_owner || '.' || - a_type_name || '; - begin - :anydata := anydata.convertobject(l_v); - end;' - using in out l_anydata; - - l_typecode := l_anydata.gettype(l_anytype); - - return l_anytype; - end; - - member function get_user_defined_type(a_data anydata) return anytype is - l_anytype anytype; - l_typecode pls_integer; - begin - l_typecode:=a_data.gettype(l_anytype); - return l_anytype; - end; - - member function get_anydata_from_compound_data(a_owner varchar2, a_type_name varchar2,a_type varchar2) return anydata is - l_anydata anydata; - begin - execute immediate ' - declare - l_obj '||a_owner||'.'||a_type_name||'; - begin - :anydata := sys.anydata.convert'||a_type||'(l_obj); - end;' - using out l_anydata; - return l_anydata; - end; - - member function get_anytype_of_coll_element(a_collection_owner in varchar2, a_collection_name in varchar2) - return anytype is - l_anytype anytype; - l_anydata anydata; - l_owner varchar2(100); - l_type_name varchar2(100); - begin - l_anydata := get_anydata_from_compound_data(a_collection_owner,a_collection_name,'collection'); - execute immediate' - declare - l_data '||a_collection_owner||'.'||a_collection_name||'; - l_value anydata := :a_value; - l_status integer; - l_loc_query sys_refcursor; - l_cursor_number number; - l_columns_count pls_integer; - l_columns_desc dbms_sql.desc_tab3; - begin - l_status := l_value.getcollection(l_data); - l_data := '||a_collection_owner||'.'||a_collection_name||q'[(); - l_data.extend; - open l_loc_query for select l_data(1) from dual; - l_cursor_number := dbms_sql.to_cursor_number(l_loc_query); - dbms_sql.describe_columns3(l_cursor_number, - l_columns_count, - l_columns_desc); - :owner := l_columns_desc(1).col_schema_name; - :type_name := l_columns_desc(1).col_type_name; - dbms_sql.close_cursor(l_cursor_number); - end;]' using l_anydata, out l_owner,out l_type_name; - l_anytype := get_user_defined_type(l_owner, l_type_name); - return l_anytype; - end; - - member procedure desc_compound_data(self in out nocopy ut_cursor_details,a_compound_data anytype, - a_parent_name in varchar2,a_level in integer, a_access_path in varchar2) is - l_idx pls_integer := 1; - l_elements_count pls_integer; - l_attribute_typecode pls_integer; - l_aname varchar2(32767); - l_len pls_integer; - l_is_collection boolean; - l_schema_name varchar2(100); - l_hierarchy_level integer := a_level; - l_object_type varchar2(10); - l_anydata anydata; - l_attr_elt_type anytype; - begin - get_anytype_members_info(a_compound_data,l_attribute_typecode,l_schema_name,l_aname,l_len,l_elements_count); - while l_idx <= nvl(l_elements_count,1) loop - if l_elements_count is not null then - getattreleminfo(a_compound_data,l_idx,l_attribute_typecode,l_aname,l_len,l_attr_elt_type); - elsif l_attribute_typecode in (dbms_types.typecode_table, dbms_types.typecode_varray, dbms_types.typecode_namedcollection) then - l_attr_elt_type := get_anytype_of_coll_element(l_schema_name, l_aname); - end if; - - l_is_collection := ut_compound_data_helper.is_collection(l_attribute_typecode); - self.cursor_columns_info.extend; - self.cursor_columns_info(cursor_columns_info.last) := ut_cursor_column( l_aname, - l_schema_name, - null, - l_len, - a_parent_name, - l_hierarchy_level, - l_idx, - ut_compound_data_helper.get_column_type_desc(l_attribute_typecode,false), - ut_utils.boolean_to_int(l_is_collection), - a_access_path - ); - if l_attr_elt_type is not null then - desc_compound_data(l_attr_elt_type,l_aname,l_hierarchy_level+1,a_access_path||'/'||l_aname); - end if; - l_idx := l_idx + 1; - end loop; - end; - - constructor function ut_cursor_details(self in out nocopy ut_cursor_details) return self as result is - begin - self.cursor_columns_info := ut_cursor_column_tab(); - return; - end; - - constructor function ut_cursor_details(self in out nocopy ut_cursor_details - ,a_cursor_number in number) - return self as result is - l_cursor_number integer; - l_columns_count pls_integer; - l_columns_desc dbms_sql.desc_tab3; - l_anydata anydata; - l_is_collection boolean; - l_object_type varchar2(10); - l_hierarchy_level integer := 1; - l_anytype anytype; - begin - self.cursor_columns_info := ut_cursor_column_tab(); - dbms_sql.describe_columns3(a_cursor_number, - l_columns_count, - l_columns_desc); - - /** - * Due to a bug with object being part of cursor in anydata scanario - * oracle fails to revert number to cursor. We ar using dbms_sql.close cursor to close it - * to avoid leaving open cursors behind. - * a_cursor := dbms_sql.to_refcursor(l_cursor_number); - **/ - for cur in 1 .. l_columns_count loop - l_is_collection := ut_compound_data_helper.is_collection(l_columns_desc(cur).col_schema_name,l_columns_desc(cur).col_type_name); - self.cursor_columns_info.extend; - self.cursor_columns_info(cursor_columns_info.last) := ut_cursor_column( l_columns_desc(cur).col_name, - l_columns_desc(cur).col_schema_name, - l_columns_desc(cur).col_type_name, - l_columns_desc(cur).col_max_len, - null, - l_hierarchy_level, - cur, - ut_compound_data_helper.get_column_type_desc(l_columns_desc(cur).col_type,true), - ut_utils.boolean_to_int(l_is_collection), - null - ); - - if l_columns_desc(cur).col_type = dbms_sql.user_defined_type or l_is_collection then - l_object_type := case when l_is_collection then 'collection' else 'object' end; - l_anydata := get_anydata_from_compound_data(l_columns_desc(cur).col_schema_name, l_columns_desc(cur).col_type_name, - l_object_type); - l_anytype := get_user_defined_type(l_anydata); - desc_compound_data(l_anytype,l_columns_desc(cur).col_name,l_hierarchy_level+1,l_columns_desc(cur).col_name); - end if; - end loop; - return; - end; - - member procedure ordered_columns(self in out nocopy ut_cursor_details,a_ordered_columns boolean := false) is - begin - self.is_column_order_enforced := ut_utils.boolean_to_int(a_ordered_columns); - end; - -end; -/ +create or replace type body ut_cursor_details as + + order member function compare(a_other ut_cursor_details) return integer is + l_diffs integer; + begin + if self.is_column_order_enforced = 1 then + select count(1) into l_diffs + from table(self.cursor_columns_info) a + full outer join table(a_other.cursor_columns_info) e + on decode(a.parent_name,e.parent_name,1,0)= 1 + and a.column_name = e.column_name + and replace(a.column_type,'VARCHAR2','CHAR') = replace(e.column_type,'VARCHAR2','CHAR') + and a.column_position = e.column_position + where a.column_name is null or e.column_name is null; + else + select count(1) into l_diffs + from table(self.cursor_columns_info) a + full outer join table(a_other.cursor_columns_info) e + on decode(a.parent_name,e.parent_name,1,0)= 1 + and a.column_name = e.column_name + and replace(a.column_type,'VARCHAR2','CHAR') = replace(e.column_type,'VARCHAR2','CHAR') + where a.column_name is null or e.column_name is null; + end if; + return l_diffs; + end; + + member procedure get_anytype_members_info(a_anytype anytype, a_attribute_typecode out pls_integer, + a_schema_name out varchar2, a_type_name out varchar2, a_len out pls_integer,a_elements_count out pls_integer) is + l_version varchar2(32767); + l_prec pls_integer; + l_scale pls_integer; + l_csid pls_integer; + l_csfrm pls_integer; + begin + a_attribute_typecode := a_anytype.getinfo( + prec => l_prec, + scale => l_scale, + len => a_len, + csid => l_csid, + csfrm => l_csfrm, + schema_name => a_schema_name, + type_name => a_type_name, + version => l_version, + numelems => a_elements_count + ); + end; + + member procedure getattreleminfo(a_anytype anytype,a_pos pls_integer, a_attribute_typecode out pls_integer, + a_type_name out varchar2, a_len out pls_integer, a_attr_elt_type out anytype) is + l_prec pls_integer; + l_scale pls_integer; + l_csid pls_integer; + l_csfrm pls_integer; + l_attr_elt_type anytype; + begin + a_attribute_typecode := a_anytype.getattreleminfo( + pos => a_pos, --First attribute + prec => l_prec, + scale => l_scale, + len => a_len, + csid => l_csid, + csfrm => l_csfrm, + attr_elt_type => l_attr_elt_type, + aname => a_type_name + ); + end; + + member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) + return anytype is + l_anydata anydata; + l_anytype anytype; + l_typecode pls_integer; + begin + execute immediate 'declare + l_v ' || a_owner || '.' || a_type_name || '; + begin + :anydata := anydata.convertobject(l_v); + end;' + using in out l_anydata; + + l_typecode := l_anydata.gettype(l_anytype); + + return l_anytype; + end; + + member function get_user_defined_type(a_data anydata) return anytype is + l_anytype anytype; + l_typecode pls_integer; + begin + l_typecode:=a_data.gettype(l_anytype); + return l_anytype; + end; + + member function get_anydata_from_compound_data(a_owner varchar2, a_type_name varchar2,a_type varchar2) return anydata is + l_anydata anydata; + begin + execute immediate ' + declare + l_obj '||a_owner||'.'||a_type_name||'; + begin + :anydata := sys.anydata.convert'||a_type||'(l_obj); + end;' + using out l_anydata; + return l_anydata; + end; + + member function get_anytype_of_coll_element(a_collection_owner in varchar2, a_collection_name in varchar2) + return anytype is + l_anytype anytype; + l_anydata anydata; + l_owner varchar2(100); + l_type_name varchar2(100); + begin + l_anydata := get_anydata_from_compound_data(a_collection_owner,a_collection_name,'collection'); + execute immediate' + declare + l_data '||a_collection_owner||'.'||a_collection_name||'; + l_value anydata := :a_value; + l_status integer; + l_loc_query sys_refcursor; + l_cursor_number number; + l_columns_count pls_integer; + l_columns_desc dbms_sql.desc_tab3; + begin + l_status := l_value.getcollection(l_data); + l_data := '||a_collection_owner||'.'||a_collection_name||q'[(); + l_data.extend; + open l_loc_query for select l_data(1) from dual; + l_cursor_number := dbms_sql.to_cursor_number(l_loc_query); + dbms_sql.describe_columns3(l_cursor_number, + l_columns_count, + l_columns_desc); + :owner := l_columns_desc(1).col_schema_name; + :type_name := l_columns_desc(1).col_type_name; + dbms_sql.close_cursor(l_cursor_number); + end;]' using l_anydata, out l_owner,out l_type_name; + l_anytype := get_user_defined_type(l_owner, l_type_name); + return l_anytype; + end; + + member procedure desc_compound_data(self in out nocopy ut_cursor_details,a_compound_data anytype, + a_parent_name in varchar2,a_level in integer, a_access_path in varchar2) is + l_idx pls_integer := 1; + l_elements_count pls_integer; + l_attribute_typecode pls_integer; + l_aname varchar2(32767); + l_len pls_integer; + l_is_collection boolean; + l_schema_name varchar2(100); + l_hierarchy_level integer := a_level; + l_attr_elt_type anytype; + begin + get_anytype_members_info(a_compound_data,l_attribute_typecode,l_schema_name,l_aname,l_len,l_elements_count); + while l_idx <= nvl(l_elements_count,1) loop + if l_elements_count is not null then + getattreleminfo(a_compound_data,l_idx,l_attribute_typecode,l_aname,l_len,l_attr_elt_type); + elsif l_attribute_typecode in (dbms_types.typecode_table, dbms_types.typecode_varray, dbms_types.typecode_namedcollection) then + l_attr_elt_type := get_anytype_of_coll_element(l_schema_name, l_aname); + end if; + + l_is_collection := ut_compound_data_helper.is_collection(l_attribute_typecode); + self.cursor_columns_info.extend; + self.cursor_columns_info(cursor_columns_info.last) := + ut_cursor_column( + l_aname, + l_schema_name, + null, + l_len, + a_parent_name, + l_hierarchy_level, + l_idx, + ut_compound_data_helper.get_column_type_desc(l_attribute_typecode,false), + ut_utils.boolean_to_int(l_is_collection), + a_access_path + ); + if l_attr_elt_type is not null then + desc_compound_data(l_attr_elt_type,l_aname,l_hierarchy_level+1,a_access_path||'/'||l_aname); + end if; + l_idx := l_idx + 1; + end loop; + end; + + constructor function ut_cursor_details(self in out nocopy ut_cursor_details) return self as result is + begin + self.cursor_columns_info := ut_cursor_column_tab(); + return; + end; + + constructor function ut_cursor_details( + self in out nocopy ut_cursor_details, + a_cursor_number in number + ) return self as result is + l_columns_count pls_integer; + l_columns_desc dbms_sql.desc_tab3; + l_anydata anydata; + l_is_collection boolean; + l_object_type varchar2(10); + l_hierarchy_level integer := 1; + l_anytype anytype; + begin + self.cursor_columns_info := ut_cursor_column_tab(); + dbms_sql.describe_columns3(a_cursor_number, l_columns_count, l_columns_desc); + + /** + * Due to a bug with object being part of cursor in anydata scanario + * oracle fails to revert number to cursor. We ar using dbms_sql.close cursor to close it + * to avoid leaving open cursors behind. + * a_cursor := dbms_sql.to_refcursor(l_cursor_number); + **/ + for cur in 1 .. l_columns_count loop + l_is_collection := ut_compound_data_helper.is_collection( + l_columns_desc(cur).col_schema_name, + l_columns_desc(cur).col_type_name + ); + self.cursor_columns_info.extend; + self.cursor_columns_info(cursor_columns_info.last) := + ut_cursor_column( + l_columns_desc(cur).col_name, + l_columns_desc(cur).col_schema_name, + l_columns_desc(cur).col_type_name, + l_columns_desc(cur).col_max_len, + null, + l_hierarchy_level, + cur, + ut_compound_data_helper.get_column_type_desc(l_columns_desc(cur).col_type,true), + ut_utils.boolean_to_int(l_is_collection), + null + ); + + if l_columns_desc(cur).col_type = dbms_sql.user_defined_type or l_is_collection then + l_object_type := case when l_is_collection then 'collection' else 'object' end; + l_anydata := get_anydata_from_compound_data( + l_columns_desc(cur).col_schema_name, + l_columns_desc(cur).col_type_name, + l_object_type + ); + l_anytype := get_user_defined_type(l_anydata); + desc_compound_data( l_anytype, l_columns_desc(cur).col_name, l_hierarchy_level+1, l_columns_desc(cur).col_name ); + end if; + end loop; + return; + end; + + member procedure ordered_columns(self in out nocopy ut_cursor_details,a_ordered_columns boolean := false) is + begin + self.is_column_order_enforced := ut_utils.boolean_to_int(a_ordered_columns); + end; + +end; +/ diff --git a/source/expectations/matchers/ut_include.tpb b/source/expectations/matchers/ut_include.tpb index a0e463184..dbf014eb8 100644 --- a/source/expectations/matchers/ut_include.tpb +++ b/source/expectations/matchers/ut_include.tpb @@ -55,8 +55,14 @@ create or replace type body ut_include as begin if self.expected.data_type = a_actual.data_type then l_actual := treat(a_actual as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,self.get_ordered_columns()); - l_result := 0 = treat(self.expected as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,self.get_ordered_columns()).compare_implementation(l_actual, - true,self.get_inclusion_compare(), self.get_negated(), self.get_join_by_list()); + l_result := + ( 0 + = treat( self.expected as ut_data_value_refcursor ).update_cursor_details( + exclude_list, include_list, self.get_ordered_columns( ) + ).compare_implementation( + l_actual, true, self.get_inclusion_compare( ), self.get_negated( ), self.get_join_by_list( ) + ) + ); else l_result := (self as ut_matcher).run_matcher(a_actual); end if; @@ -76,7 +82,10 @@ create or replace type body ut_include as l_actual := treat(a_actual as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,self.get_ordered_columns()); l_result := 'Actual: '||a_actual.get_object_info()||' '||self.description()||': '||self.expected.get_object_info() - || chr(10) || 'Diff:' || treat(expected as ut_data_value_refcursor).update_cursor_details(exclude_list, include_list,self.get_ordered_columns()).diff(l_actual, true, self.get_join_by_list()); + || chr(10) || 'Diff:' + || treat(expected as ut_data_value_refcursor).update_cursor_details( + exclude_list, include_list, self.get_ordered_columns() + ).diff(l_actual, true, self.get_join_by_list()); else l_result := (self as ut_matcher).failure_message(a_actual) || ': '|| self.expected.to_string_report(); end if; From 004b5370ad716c14bdc9344b6e2902c4f7afb38d Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Mon, 10 Dec 2018 22:32:27 +0000 Subject: [PATCH 78/83] Refactoring recursive calls for resolving complex types in cursor. Changed `is_collection` and moved to `ut_cursor_column` Changed `get_anytype_members_info`, `get_attr_elem_info` and moved to `ut_compound_data_helper` Fixes to formatting. --- .../data_values/ut_compound_data_helper.pkb | 69 +++-- .../data_values/ut_compound_data_helper.pks | 74 +++-- .../data_values/ut_compound_data_value.tpb | 5 +- .../data_values/ut_cursor_column.tps | 77 +++-- .../data_values/ut_cursor_column_tab.tps | 19 +- .../data_values/ut_cursor_details.tpb | 280 ++++++++---------- .../data_values/ut_cursor_details.tps | 60 ++-- 7 files changed, 316 insertions(+), 268 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 0e3ffdcfa..8bc556e78 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -16,15 +16,12 @@ create or replace package body ut_compound_data_helper is limitations under the License. */ - g_user_defined_type pls_integer := dbms_sql.user_defined_type; g_diff_count integer; - g_filter_tab ut_varchar2_list; - + type t_type_name_map is table of varchar2(128) index by binary_integer; g_type_name_map t_type_name_map; g_anytype_name_map t_type_name_map; - g_anytype_collection_name t_type_name_map; - + function get_columns_filter( a_exclude_xpath varchar2, a_include_xpath varchar2, a_table_alias varchar2 := 'ucd', a_column_alias varchar2 := 'item_data' @@ -228,7 +225,6 @@ create or replace package body ut_compound_data_helper is end; procedure generate_select_stmt(a_data_info ut_cursor_column,a_sql_stmt in out nocopy clob, a_col_name varchar2,a_alias varchar2 := 'ucd.') is - l_sql_stmt clob; l_alias varchar2(10) := a_alias; l_col_syntax varchar2(4000); l_ut_owner varchar2(250) := ut_utils.ut_owner; @@ -326,13 +322,14 @@ create or replace package body ut_compound_data_helper is end; - function gen_compare_sql(a_inclusion_type boolean, a_is_negated boolean,a_unordered boolean, - a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob is + function gen_compare_sql( + a_inclusion_type boolean, a_is_negated boolean, a_unordered boolean, + a_other ut_data_value_refcursor := null, a_join_by_list ut_varchar2_list := ut_varchar2_list() + ) return clob is l_compare_sql clob; l_temp_string varchar2(32767); l_xmltable_stmt clob; - l_where_stmt clob; l_select_stmt clob; l_partition_stmt clob; l_equal_stmt clob; @@ -780,35 +777,47 @@ create or replace package body ut_compound_data_helper is end if; end; - function is_collection (a_anytype_code in integer) return boolean is + function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is begin - return a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection); + return case when a_dbms_sql_desc then g_type_name_map(a_type_code) else g_anytype_name_map(a_type_code) end; end; - function is_collection (a_owner varchar2, a_type_name varchar2, a_anytype_code in integer :=null) return boolean is - l_type_view varchar2(200) := ut_metadata.get_dba_view('dba_types'); - l_typecode varchar2(100); - begin - if a_anytype_code is null then - execute immediate 'select typecode from '||l_type_view ||' - where owner = :owner and type_name = :typename' - into l_typecode using a_owner,a_type_name; - - return l_typecode = 'COLLECTION'; - else - return is_collection(a_anytype_code); + function get_anytype_members_info( a_anytype anytype ) return t_anytype_members_rec is + l_result t_anytype_members_rec; + begin + if a_anytype is not null then + l_result.type_code := a_anytype.getinfo( + prec => l_result.precision, + scale => l_result.scale, + len => l_result.length, + csid => l_result.char_set_id, + csfrm => l_result.char_set_frm, + schema_name => l_result.schema_name, + type_name => l_result.type_name, + version => l_result.version, + numelems => l_result.elements_count + ); end if; - - exception - when no_data_found then - return false; + return l_result; end; - function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is + function get_attr_elem_info( a_anytype anytype, a_pos pls_integer := null ) return t_anytype_elem_info_rec is + l_result t_anytype_elem_info_rec; begin - return case when a_dbms_sql_desc then g_type_name_map(a_type_code) else g_anytype_name_map(a_type_code) end; + if a_anytype is not null then + l_result.type_code := a_anytype.getattreleminfo( + pos => a_pos, + prec => l_result.precision, + scale => l_result.scale, + len => l_result.length, + csid => l_result.char_set_id, + csfrm => l_result.char_set_frm, + attr_elt_type => l_result.attr_elt_type, + aname => l_result.attribute_name + ); + end if; + return l_result; end; - begin g_anytype_name_map(dbms_types.typecode_date) := 'DATE'; diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index 290c101cc..de988e489 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -54,8 +54,33 @@ create or replace package ut_compound_data_helper authid definer is exp_data_id raw(32), item_no number, dup_no number - ); - + ); + + type t_anytype_members_rec is record ( + type_code pls_integer, + schema_name varchar2(128), + type_name varchar2(128), + length pls_integer, + elements_count pls_integer, + version varchar2(32767), + precision pls_integer, + scale pls_integer, + char_set_id pls_integer, + char_set_frm pls_integer + ); + + type t_anytype_elem_info_rec is record ( + type_code pls_integer, + attribute_name varchar2(260), + length pls_integer, + version varchar2(32767), + precision pls_integer, + scale pls_integer, + char_set_id pls_integer, + char_set_frm pls_integer, + attr_elt_type anytype + ); + type t_diff_tab is table of t_diff_rec; function get_columns_filter( @@ -63,15 +88,16 @@ create or replace package ut_compound_data_helper authid definer is a_table_alias varchar2 := 'ucd', a_column_alias varchar2 := 'item_data' ) return varchar2; - function get_columns_diff(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab,a_order_enforced boolean := false) - return tt_column_diffs; + function get_columns_diff( + a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab,a_order_enforced boolean := false + ) return tt_column_diffs; - function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob; + function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob; - function get_rows_diff( + function get_rows_diff( a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2 - ) return tt_row_diffs; + ) return tt_row_diffs; function get_rows_diff_by_sql(a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, @@ -85,8 +111,10 @@ create or replace package ut_compound_data_helper authid definer is function get_fixed_size_hash(a_string varchar2, a_base integer :=0,a_size integer :=9999999) return number; - function gen_compare_sql(a_inclusion_type boolean, a_is_negated boolean, a_unordered boolean, - a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return clob; + function gen_compare_sql( + a_inclusion_type boolean, a_is_negated boolean, a_unordered boolean, + a_other ut_data_value_refcursor :=null, a_join_by_list ut_varchar2_list:=ut_varchar2_list() + ) return clob; procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw); @@ -96,28 +124,34 @@ create or replace package ut_compound_data_helper authid definer is function get_rows_diff_count return integer; - function filter_out_cols(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list,a_include boolean := true) - return ut_cursor_column_tab; + function filter_out_cols( + a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list,a_include boolean := true + ) return ut_cursor_column_tab; - function get_missing_pk(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab, a_current_list ut_varchar2_list) - return tt_missing_pk; + function get_missing_pk( + a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab, a_current_list ut_varchar2_list + ) return tt_missing_pk; - function inc_exc_columns_from_cursor (a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list) - return ut_cursor_column_tab; + function inc_exc_columns_from_cursor ( + a_cursor_info ut_cursor_column_tab, a_exclude_xpath ut_varchar2_list, a_include_xpath ut_varchar2_list + ) return ut_cursor_column_tab; function contains_collection (a_cursor_info ut_cursor_column_tab) return number; - function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list) return ut_cursor_column_tab; + function remove_incomparable_cols( + a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list + ) return ut_cursor_column_tab; function getxmlchildren(a_parent_name varchar2,a_cursor_table ut_cursor_column_tab) return xmltype; function is_sql_compare_allowed(a_type_name varchar2) return boolean; - function is_collection (a_owner varchar2,a_type_name varchar2, a_anytype_code in integer :=null) return boolean; + function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2; - function is_collection (a_anytype_code in integer) return boolean; - function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2; - + function get_anytype_members_info( a_anytype anytype ) return t_anytype_members_rec; + + function get_attr_elem_info( a_anytype anytype, a_pos pls_integer := null ) return t_anytype_elem_info_rec; + end; / diff --git a/source/expectations/data_values/ut_compound_data_value.tpb b/source/expectations/data_values/ut_compound_data_value.tpb index 860bc2ae3..6c67060fb 100644 --- a/source/expectations/data_values/ut_compound_data_value.tpb +++ b/source/expectations/data_values/ut_compound_data_value.tpb @@ -210,7 +210,10 @@ create or replace type body ut_compound_data_value as begin l_other := treat(a_other as ut_compound_data_value); l_diff_id := ut_compound_data_helper.get_hash(self.data_id||l_other.data_id); - +-- dbms_output.put_line(ut_compound_data_helper.gen_compare_sql( +-- a_inclusion_compare, a_is_negated, a_unordered, +-- treat(a_other as ut_data_value_refcursor), a_join_by_list +-- )); open l_loop_curs for ut_compound_data_helper.gen_compare_sql( a_inclusion_compare, a_is_negated, a_unordered, diff --git a/source/expectations/data_values/ut_cursor_column.tps b/source/expectations/data_values/ut_cursor_column.tps index dae1fc16d..4b436051a 100644 --- a/source/expectations/data_values/ut_cursor_column.tps +++ b/source/expectations/data_values/ut_cursor_column.tps @@ -1,31 +1,46 @@ -create or replace type ut_cursor_column force authid current_user as object -( - parent_name varchar2(4000), - access_path varchar2(4000), - has_nested_col number(1,0), - transformed_name varchar2(32), - hierarchy_level number, - column_position number, - xml_valid_name varchar2(128), - column_name varchar2(128), - column_type varchar2(128), - column_type_name varchar2(128), - column_schema varchar2(128), - column_len integer, - is_sql_diffable number(1, 0), - is_collection number(1, 0), - - member procedure init(self in out nocopy ut_cursor_column, - a_col_name varchar2, a_col_schema_name varchar2, - a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, - a_col_position integer, a_col_type in varchar2, a_collection integer,a_access_path in varchar2), - - constructor function ut_cursor_column( self in out nocopy ut_cursor_column, - a_col_name varchar2, a_col_schema_name varchar2, - a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, - a_col_position integer, a_col_type in varchar2, a_collection integer,a_access_path in varchar2) - return self as result, - - constructor function ut_cursor_column( self in out nocopy ut_cursor_column) return self as result -) -/ +create or replace type ut_cursor_column force authid current_user as object ( + /* + utPLSQL - Version 3 + Copyright 2016 - 2018 utPLSQL Project + + Licensed under the Apache License, Version 2.0 (the "License"): + you may not use this file except in compliance with the License. + You may obtain a copy of the License at + + http://www.apache.org/licenses/LICENSE-2.0 + + Unless required by applicable law or agreed to in writing, software + distributed under the License is distributed on an "AS IS" BASIS, + WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + See the License for the specific language governing permissions and + limitations under the License. + */ + parent_name varchar2(4000), + access_path varchar2(4000), + has_nested_col number(1,0), + transformed_name varchar2(32), + hierarchy_level number, + column_position number, + xml_valid_name varchar2(128), + column_name varchar2(128), + column_type varchar2(128), + column_type_name varchar2(128), + column_schema varchar2(128), + column_len integer, + is_sql_diffable number(1, 0), + is_collection number(1, 0), + + member procedure init(self in out nocopy ut_cursor_column, + a_col_name varchar2, a_col_schema_name varchar2, + a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_position integer, a_col_type in varchar2, a_collection integer,a_access_path in varchar2), + + constructor function ut_cursor_column( self in out nocopy ut_cursor_column, + a_col_name varchar2, a_col_schema_name varchar2, + a_col_type_name varchar2, a_col_max_len integer, a_parent_name varchar2 := null, a_hierarchy_level integer := 1, + a_col_position integer, a_col_type in varchar2, a_collection integer, a_access_path in varchar2) + return self as result, + + constructor function ut_cursor_column( self in out nocopy ut_cursor_column) return self as result +) +/ diff --git a/source/expectations/data_values/ut_cursor_column_tab.tps b/source/expectations/data_values/ut_cursor_column_tab.tps index 05516854a..1b7a1698f 100644 --- a/source/expectations/data_values/ut_cursor_column_tab.tps +++ b/source/expectations/data_values/ut_cursor_column_tab.tps @@ -1,2 +1,19 @@ -create or replace type ut_cursor_column_tab as table of ut_cursor_column +create or replace type ut_cursor_column_tab as + /* + utPLSQL - Version 3 + Copyright 2016 - 2018 utPLSQL Project + + Licensed under the Apache License, Version 2.0 (the "License"): + you may not use this file except in compliance with the License. + You may obtain a copy of the License at + + http://www.apache.org/licenses/LICENSE-2.0 + + Unless required by applicable law or agreed to in writing, software + distributed under the License is distributed on an "AS IS" BASIS, + WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + See the License for the specific language governing permissions and + limitations under the License. + */ +table of ut_cursor_column / \ No newline at end of file diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index beb60e44d..8204c95b5 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -23,161 +23,90 @@ create or replace type body ut_cursor_details as end if; return l_diffs; end; - - member procedure get_anytype_members_info(a_anytype anytype, a_attribute_typecode out pls_integer, - a_schema_name out varchar2, a_type_name out varchar2, a_len out pls_integer,a_elements_count out pls_integer) is - l_version varchar2(32767); - l_prec pls_integer; - l_scale pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - begin - a_attribute_typecode := a_anytype.getinfo( - prec => l_prec, - scale => l_scale, - len => a_len, - csid => l_csid, - csfrm => l_csfrm, - schema_name => a_schema_name, - type_name => a_type_name, - version => l_version, - numelems => a_elements_count - ); - end; - - member procedure getattreleminfo(a_anytype anytype,a_pos pls_integer, a_attribute_typecode out pls_integer, - a_type_name out varchar2, a_len out pls_integer, a_attr_elt_type out anytype) is - l_prec pls_integer; - l_scale pls_integer; - l_csid pls_integer; - l_csfrm pls_integer; - l_attr_elt_type anytype; - begin - a_attribute_typecode := a_anytype.getattreleminfo( - pos => a_pos, --First attribute - prec => l_prec, - scale => l_scale, - len => a_len, - csid => l_csid, - csfrm => l_csfrm, - attr_elt_type => l_attr_elt_type, - aname => a_type_name - ); - end; - - member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) - return anytype is - l_anydata anydata; - l_anytype anytype; - l_typecode pls_integer; + + member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return anytype is + l_anytype anytype; + not_found exception; + pragma exception_init(not_found,-22303); begin - execute immediate 'declare - l_v ' || a_owner || '.' || a_type_name || '; - begin - :anydata := anydata.convertobject(l_v); - end;' - using in out l_anydata; - - l_typecode := l_anydata.gettype(l_anytype); - + begin + $if dbms_db_version.version <= 12 $then + l_anytype := anytype.getpersistent( a_owner, a_type_name ); + $else + l_anytype := getanytypefrompersistent( a_owner, a_type_name ); + $end + exception + when not_found then + null; + end; return l_anytype; end; - member function get_user_defined_type(a_data anydata) return anytype is - l_anytype anytype; - l_typecode pls_integer; - begin - l_typecode:=a_data.gettype(l_anytype); - return l_anytype; - end; - - member function get_anydata_from_compound_data(a_owner varchar2, a_type_name varchar2,a_type varchar2) return anydata is - l_anydata anydata; - begin - execute immediate ' - declare - l_obj '||a_owner||'.'||a_type_name||'; - begin - :anydata := sys.anydata.convert'||a_type||'(l_obj); - end;' - using out l_anydata; - return l_anydata; - end; - - member function get_anytype_of_coll_element(a_collection_owner in varchar2, a_collection_name in varchar2) - return anytype is - l_anytype anytype; - l_anydata anydata; - l_owner varchar2(100); - l_type_name varchar2(100); - begin - l_anydata := get_anydata_from_compound_data(a_collection_owner,a_collection_name,'collection'); - execute immediate' - declare - l_data '||a_collection_owner||'.'||a_collection_name||'; - l_value anydata := :a_value; - l_status integer; - l_loc_query sys_refcursor; - l_cursor_number number; - l_columns_count pls_integer; - l_columns_desc dbms_sql.desc_tab3; - begin - l_status := l_value.getcollection(l_data); - l_data := '||a_collection_owner||'.'||a_collection_name||q'[(); - l_data.extend; - open l_loc_query for select l_data(1) from dual; - l_cursor_number := dbms_sql.to_cursor_number(l_loc_query); - dbms_sql.describe_columns3(l_cursor_number, - l_columns_count, - l_columns_desc); - :owner := l_columns_desc(1).col_schema_name; - :type_name := l_columns_desc(1).col_type_name; - dbms_sql.close_cursor(l_cursor_number); - end;]' using l_anydata, out l_owner,out l_type_name; - l_anytype := get_user_defined_type(l_owner, l_type_name); - return l_anytype; - end; - - member procedure desc_compound_data(self in out nocopy ut_cursor_details,a_compound_data anytype, - a_parent_name in varchar2,a_level in integer, a_access_path in varchar2) is + member procedure desc_compound_data( + self in out nocopy ut_cursor_details, a_compound_data anytype, + a_parent_name in varchar2, a_level in integer, a_access_path in varchar2 + ) is l_idx pls_integer := 1; - l_elements_count pls_integer; - l_attribute_typecode pls_integer; - l_aname varchar2(32767); - l_len pls_integer; + l_elements_info ut_compound_data_helper.t_anytype_members_rec; + l_element_info ut_compound_data_helper.t_anytype_elem_info_rec; l_is_collection boolean; - l_schema_name varchar2(100); - l_hierarchy_level integer := a_level; - l_attr_elt_type anytype; begin - get_anytype_members_info(a_compound_data,l_attribute_typecode,l_schema_name,l_aname,l_len,l_elements_count); - while l_idx <= nvl(l_elements_count,1) loop - if l_elements_count is not null then - getattreleminfo(a_compound_data,l_idx,l_attribute_typecode,l_aname,l_len,l_attr_elt_type); - elsif l_attribute_typecode in (dbms_types.typecode_table, dbms_types.typecode_varray, dbms_types.typecode_namedcollection) then - l_attr_elt_type := get_anytype_of_coll_element(l_schema_name, l_aname); - end if; - - l_is_collection := ut_compound_data_helper.is_collection(l_attribute_typecode); + + l_elements_info := ut_compound_data_helper.get_anytype_members_info( a_compound_data ); + + l_is_collection := is_collection(l_elements_info.type_code); + + if l_elements_info.elements_count is null then + + l_element_info := ut_compound_data_helper.get_attr_elem_info( a_compound_data ); + self.cursor_columns_info.extend; self.cursor_columns_info(cursor_columns_info.last) := ut_cursor_column( - l_aname, - l_schema_name, + l_elements_info.type_name, + l_elements_info.schema_name, null, - l_len, + l_elements_info.length, a_parent_name, - l_hierarchy_level, + a_level, l_idx, - ut_compound_data_helper.get_column_type_desc(l_attribute_typecode,false), + ut_compound_data_helper.get_column_type_desc(l_elements_info.type_code,false), ut_utils.boolean_to_int(l_is_collection), a_access_path ); - if l_attr_elt_type is not null then - desc_compound_data(l_attr_elt_type,l_aname,l_hierarchy_level+1,a_access_path||'/'||l_aname); + if l_element_info.attr_elt_type is not null then + desc_compound_data( + l_element_info.attr_elt_type, l_elements_info.type_name, + a_level + 1, a_access_path || '/' || l_elements_info.type_name + ); end if; - l_idx := l_idx + 1; - end loop; + else + while l_idx <= l_elements_info.elements_count loop + l_element_info := ut_compound_data_helper.get_attr_elem_info( a_compound_data, l_idx ); + + self.cursor_columns_info.extend; + self.cursor_columns_info(cursor_columns_info.last) := + ut_cursor_column( + l_element_info.attribute_name, + l_elements_info.schema_name, + null, + l_element_info.length, + a_parent_name, + a_level, + l_idx, + ut_compound_data_helper.get_column_type_desc(l_element_info.type_code,false), + ut_utils.boolean_to_int(l_is_collection), + a_access_path + ); + if l_element_info.attr_elt_type is not null then + desc_compound_data( + l_element_info.attr_elt_type, l_element_info.attribute_name, + a_level + 1, a_access_path || '/' || l_element_info.attribute_name + ); + end if; + l_idx := l_idx + 1; + end loop; + end if; end; constructor function ut_cursor_details(self in out nocopy ut_cursor_details) return self as result is @@ -192,55 +121,80 @@ create or replace type body ut_cursor_details as ) return self as result is l_columns_count pls_integer; l_columns_desc dbms_sql.desc_tab3; - l_anydata anydata; l_is_collection boolean; - l_object_type varchar2(10); l_hierarchy_level integer := 1; - l_anytype anytype; begin self.cursor_columns_info := ut_cursor_column_tab(); dbms_sql.describe_columns3(a_cursor_number, l_columns_count, l_columns_desc); /** - * Due to a bug with object being part of cursor in anydata scanario + * Due to a bug with object being part of cursor in ANYDATA scenario * oracle fails to revert number to cursor. We ar using dbms_sql.close cursor to close it * to avoid leaving open cursors behind. * a_cursor := dbms_sql.to_refcursor(l_cursor_number); **/ - for cur in 1 .. l_columns_count loop - l_is_collection := ut_compound_data_helper.is_collection( - l_columns_desc(cur).col_schema_name, - l_columns_desc(cur).col_type_name - ); + for pos in 1 .. l_columns_count loop + l_is_collection := is_collection( l_columns_desc(pos).col_schema_name, l_columns_desc(pos).col_type_name ); self.cursor_columns_info.extend; - self.cursor_columns_info(cursor_columns_info.last) := + self.cursor_columns_info(self.cursor_columns_info.last) := ut_cursor_column( - l_columns_desc(cur).col_name, - l_columns_desc(cur).col_schema_name, - l_columns_desc(cur).col_type_name, - l_columns_desc(cur).col_max_len, + l_columns_desc(pos).col_name, + l_columns_desc(pos).col_schema_name, + l_columns_desc(pos).col_type_name, + l_columns_desc(pos).col_max_len, null, l_hierarchy_level, - cur, - ut_compound_data_helper.get_column_type_desc(l_columns_desc(cur).col_type,true), + pos, + ut_compound_data_helper.get_column_type_desc(l_columns_desc(pos).col_type,true), ut_utils.boolean_to_int(l_is_collection), null ); - - if l_columns_desc(cur).col_type = dbms_sql.user_defined_type or l_is_collection then - l_object_type := case when l_is_collection then 'collection' else 'object' end; - l_anydata := get_anydata_from_compound_data( - l_columns_desc(cur).col_schema_name, - l_columns_desc(cur).col_type_name, - l_object_type + if l_columns_desc(pos).col_type = dbms_sql.user_defined_type or l_is_collection then + desc_compound_data( + get_user_defined_type( l_columns_desc(pos).col_schema_name, l_columns_desc(pos).col_type_name ), + l_columns_desc(pos).col_name, + l_hierarchy_level + 1, + l_columns_desc(pos).col_name ); - l_anytype := get_user_defined_type(l_anydata); - desc_compound_data( l_anytype, l_columns_desc(cur).col_name, l_hierarchy_level+1, l_columns_desc(cur).col_name ); end if; end loop; return; end; + member function get_anytype_from_name( + a_owner in varchar2, a_type_name in varchar2 + ) return anytype is + l_result anytype; + e_not_found exception; + pragma exception_init(e_not_found,-22303); + begin + begin + $if dbms_db_version.version <= 12 $then + l_result := anytype.getpersistent( a_owner, a_type_name ); + $else + l_result := getanytypefrompersistent( a_owner, a_type_name ); + $end + exception + when e_not_found then + null; + end; + return l_result; + end; + + member function is_collection (a_anytype_code in integer) return boolean is + begin + return coalesce(a_anytype_code in (dbms_types.typecode_varray,dbms_types.typecode_table,dbms_types.typecode_namedcollection),false); + end; + + member function is_collection (a_owner varchar2, a_type_name varchar2) return boolean is + begin + return is_collection( + ut_compound_data_helper.get_anytype_members_info( + get_anytype_from_name(a_owner, a_type_name) + ).type_code + ); + end; + member procedure ordered_columns(self in out nocopy ut_cursor_details,a_ordered_columns boolean := false) is begin self.is_column_order_enforced := ut_utils.boolean_to_int(a_ordered_columns); diff --git a/source/expectations/data_values/ut_cursor_details.tps b/source/expectations/data_values/ut_cursor_details.tps index eb0f09f96..545106d35 100644 --- a/source/expectations/data_values/ut_cursor_details.tps +++ b/source/expectations/data_values/ut_cursor_details.tps @@ -1,22 +1,38 @@ -create or replace type ut_cursor_details force authid current_user as object -( - cursor_columns_info ut_cursor_column_tab, - is_column_order_enforced number(1,0), - order member function compare(a_other ut_cursor_details) return integer, - member procedure get_anytype_members_info(a_anytype anytype, a_attribute_typecode out pls_integer, - a_schema_name out varchar2, a_type_name out varchar2, a_len out pls_integer,a_elements_count out pls_integer), - member procedure getattreleminfo(a_anytype anytype,a_pos pls_integer, a_attribute_typecode out pls_integer, - a_type_name out varchar2, a_len out pls_integer,a_attr_elt_type out anytype), - member function get_anytype_of_coll_element(a_collection_owner in varchar2, a_collection_name in varchar2) - return anytype, - member procedure desc_compound_data(self in out nocopy ut_cursor_details,a_compound_data anytype, - a_parent_name in varchar2,a_level in integer,a_access_path in varchar2), - member function get_anydata_from_compound_data(a_owner varchar2, a_type_name varchar2,a_type varchar2) return anydata, - member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return anytype, - member function get_user_defined_type(a_data anydata) return anytype, - constructor function ut_cursor_details(self in out nocopy ut_cursor_details) return self as result, - constructor function ut_cursor_details(self in out nocopy ut_cursor_details,a_cursor_number in number) - return self as result, - member procedure ordered_columns(self in out nocopy ut_cursor_details,a_ordered_columns boolean := false) -) -/ +create or replace type ut_cursor_details force authid current_user as object ( + /* + utPLSQL - Version 3 + Copyright 2016 - 2018 utPLSQL Project + + Licensed under the Apache License, Version 2.0 (the "License"): + you may not use this file except in compliance with the License. + You may obtain a copy of the License at + + http://www.apache.org/licenses/LICENSE-2.0 + + Unless required by applicable law or agreed to in writing, software + distributed under the License is distributed on an "AS IS" BASIS, + WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + See the License for the specific language governing permissions and + limitations under the License. + */ + cursor_columns_info ut_cursor_column_tab, + is_column_order_enforced number(1,0), + + constructor function ut_cursor_details(self in out nocopy ut_cursor_details) return self as result, + constructor function ut_cursor_details( + self in out nocopy ut_cursor_details,a_cursor_number in number + ) return self as result, + order member function compare(a_other ut_cursor_details) return integer, + member procedure desc_compound_data( + self in out nocopy ut_cursor_details, a_compound_data anytype, + a_parent_name in varchar2, a_level in integer, a_access_path in varchar2 + ), + member function get_user_defined_type(a_owner varchar2, a_type_name varchar2) return anytype, + member function get_anytype_from_name( + a_owner in varchar2, a_type_name in varchar2 + ) return anytype, + member function is_collection(a_anytype_code in integer) return boolean, + member function is_collection(a_owner varchar2, a_type_name varchar2) return boolean, + member procedure ordered_columns(self in out nocopy ut_cursor_details, a_ordered_columns boolean := false) +) +/ From ada957d5a73348906bb8d9b3a62119032e05f2c9 Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Mon, 10 Dec 2018 23:27:21 +0000 Subject: [PATCH 79/83] Fixed exception handling on `anytype.getpersistent` --- source/expectations/data_values/ut_cursor_details.tpb | 4 +--- 1 file changed, 1 insertion(+), 3 deletions(-) diff --git a/source/expectations/data_values/ut_cursor_details.tpb b/source/expectations/data_values/ut_cursor_details.tpb index 8204c95b5..36bc9d6a1 100644 --- a/source/expectations/data_values/ut_cursor_details.tpb +++ b/source/expectations/data_values/ut_cursor_details.tpb @@ -165,8 +165,6 @@ create or replace type body ut_cursor_details as a_owner in varchar2, a_type_name in varchar2 ) return anytype is l_result anytype; - e_not_found exception; - pragma exception_init(e_not_found,-22303); begin begin $if dbms_db_version.version <= 12 $then @@ -175,7 +173,7 @@ create or replace type body ut_cursor_details as l_result := getanytypefrompersistent( a_owner, a_type_name ); $end exception - when e_not_found then + when others then null; end; return l_result; From 2ff110d4b1269e41ba7ebb40e56675446eaaaa6a Mon Sep 17 00:00:00 2001 From: lwasylow Date: Tue, 11 Dec 2018 12:44:10 +0000 Subject: [PATCH 80/83] Change cursor behaviour to be ordered columns by default. --- docs/userguide/expectations.md | 6 +++--- source/expectations/matchers/ut_equal.tpb | 6 +++--- source/expectations/matchers/ut_equal.tps | 2 +- .../expectations/ut_expectation_compound.tpb | 10 +++++----- .../expectations/ut_expectation_compound.tps | 4 ++-- .../expectations/test_expectations_cursor.pkb | 20 +++++++++---------- 6 files changed, 24 insertions(+), 24 deletions(-) diff --git a/docs/userguide/expectations.md b/docs/userguide/expectations.md index 04a5fef18..bccc027f8 100644 --- a/docs/userguide/expectations.md +++ b/docs/userguide/expectations.md @@ -713,7 +713,7 @@ utPLSQL is capable of comparing compound data-types including: - Attributes in nested table and array types are compared as **ordered lists of elements**. If order of attributes in nested table and array differ, expectation will fail. -- Columns in cursors are compared as **unordered list of elements** by default. If order of columns in cursor is of importance the option has to be passed to enforce column order comparison `ordered_columns` e.g. +- Columns in cursors are compared as **ordered list of elements** by default. If order of columns in cursor is not of importance the option has to be passed to enforce column order comparison ` unordered_columns` e.g. ```sql procedure ut_refcursors1 is @@ -725,7 +725,7 @@ utPLSQL is capable of comparing compound data-types including: open l_actual for select 1 user_id,'s' a_col,'test' username from dual; open l_expected for select 'test' username,'s' a_col,1 user_id from dual; --Act - ut.expect(l_actual).to_equal(l_expected).join_by('USER_ID').ordered_columns; + ut.expect(l_actual).to_equal(l_expected).join_by('USER_ID').unordered_columns; end; ``` @@ -821,7 +821,7 @@ create or replace package body test_cursor_compare as from dual union all select 'M' AS GENDER, 'LUKE' as FIRST_NAME, 'SKYWALKER' AS LAST_NAME, 2 as ID, '1000' AS SALARY from dual; - ut.expect(l_actual).to_equal(l_expected).ordered_columns; + ut.expect(l_actual).to_equal(l_expected); end; end; / diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index d575dc36c..50c6b74a1 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -254,16 +254,16 @@ create or replace type body ut_equal as return ( coalesce(join_columns, ut_varchar2_list()) ); end; - member function ordered_columns return ut_equal is + member function unordered_columns return ut_equal is l_result ut_equal := self; begin - l_result.is_column_order_enforced := ut_utils.boolean_to_int(true); + l_result.is_column_order_enforced := ut_utils.boolean_to_int(false); return l_result; end; member function get_ordered_columns return boolean is begin - return ut_utils.int_to_boolean(nvl(is_column_order_enforced,0)); + return ut_utils.int_to_boolean(nvl(is_column_order_enforced,1)); end; overriding member function run_matcher(self in out nocopy ut_equal, a_actual ut_data_value) return boolean is diff --git a/source/expectations/matchers/ut_equal.tps b/source/expectations/matchers/ut_equal.tps index de8fa4561..8278f2ed1 100644 --- a/source/expectations/matchers/ut_equal.tps +++ b/source/expectations/matchers/ut_equal.tps @@ -81,7 +81,7 @@ create or replace type ut_equal force under ut_comparison_matcher( overriding member function run_matcher(self in out nocopy ut_equal, a_actual ut_data_value) return boolean, overriding member function failure_message(a_actual ut_data_value) return varchar2, overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2, - member function ordered_columns return ut_equal, + member function unordered_columns return ut_equal, member function get_ordered_columns return boolean ) not final diff --git a/source/expectations/ut_expectation_compound.tpb b/source/expectations/ut_expectation_compound.tpb index d899c87a3..7e855c2ce 100644 --- a/source/expectations/ut_expectation_compound.tpb +++ b/source/expectations/ut_expectation_compound.tpb @@ -227,21 +227,21 @@ create or replace type body ut_expectation_compound as end if; end; - member function ordered_columns return ut_expectation_compound is + member function unordered_columns return ut_expectation_compound is l_result ut_expectation_compound; begin l_result := self; - l_result.matcher := treat(l_result.matcher as ut_equal).ordered_columns; + l_result.matcher := treat(l_result.matcher as ut_equal).unordered_columns; return l_result; end; - member procedure ordered_columns(self in ut_expectation_compound) is + member procedure unordered_columns(self in ut_expectation_compound) is begin if ut_utils.int_to_boolean(negated) then - self.not_to( treat(matcher as ut_equal).ordered_columns ); + self.not_to( treat(matcher as ut_equal).unordered_columns ); else - self.to_( treat(matcher as ut_equal).ordered_columns ); + self.to_( treat(matcher as ut_equal).unordered_columns ); end if; end; diff --git a/source/expectations/ut_expectation_compound.tps b/source/expectations/ut_expectation_compound.tps index 6dd34e077..12b43a4fd 100644 --- a/source/expectations/ut_expectation_compound.tps +++ b/source/expectations/ut_expectation_compound.tps @@ -49,8 +49,8 @@ create or replace type ut_expectation_compound under ut_expectation( member function join_by(a_columns ut_varchar2_list) return ut_expectation_compound, member procedure join_by(self in ut_expectation_compound, a_columns varchar2), member procedure join_by(self in ut_expectation_compound, a_columns ut_varchar2_list), - member function ordered_columns return ut_expectation_compound, - member procedure ordered_columns(self in ut_expectation_compound) + member function unordered_columns return ut_expectation_compound, + member procedure unordered_columns(self in ut_expectation_compound) ) final / diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index f47a72339..ce0b6e0bf 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -300,7 +300,7 @@ create or replace package body test_expectations_cursor is open l_expected for select 1 as col_1, 2 as col_2 from dual; open l_actual for select 2 as col_2, 1 as col_1 from dual; --Act - ut3.ut.expect( l_actual ).to_equal( l_expected ).ordered_columns; + ut3.ut.expect( l_actual ).to_equal( l_expected ); --Assert ut.expect(expectations.failed_expectations_data()).not_to_be_empty(); end; @@ -314,7 +314,7 @@ create or replace package body test_expectations_cursor is open l_expected for select 1 as col_1, 2 as col_2 from dual; open l_actual for select 2 as col_2, 1 as col_1 from dual; --Act - ut3.ut.expect( l_actual ).to_equal( l_expected ); + ut3.ut.expect( l_actual ).to_equal( l_expected ).unordered_columns; --Assert ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; @@ -330,7 +330,7 @@ create or replace package body test_expectations_cursor is open l_expected for select 1 as col_1, 2 as col_2,3 as col_3, 4 as col_4,5 col_5 from dual; open l_actual for select 2 as col_2, 1 as col_1,40 as col_4, 5 as col_5, 30 col_3 from dual; --Act - ut3.ut.expect( l_actual ).to_equal( l_expected ); + ut3.ut.expect( l_actual ).to_equal( l_expected ).unordered_columns; --Assert l_expected_message := q'[Actual: refcursor [ count = 1 ] was expected to equal: refcursor [ count = 1 ] %Diff: @@ -637,7 +637,7 @@ Rows: [ 1 differences ] open l_actual for select to_char(rownum) rn, rownum another_rn from dual connect by level <=2; open l_expected for select rownum rn, rownum another_rn from dual connect by level <=2; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).ordered_columns; + ut3.ut.expect(l_actual).to_equal(l_expected); l_expected_message := q'[Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ] Diff: @@ -682,7 +682,7 @@ Columns:% open l_actual for select rownum+1 col_1, rownum+2 col_2, rownum+3 col_3, rownum+4 col_4 from dual connect by level <=2; open l_expected for select rownum+1 col_1, rownum+4 col_4, rownum+2 col_2, rownum+3 col_3 from dual connect by level <=2; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).ordered_columns; + ut3.ut.expect(l_actual).to_equal(l_expected); l_expected_message := q'[Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ] Diff: @@ -707,7 +707,7 @@ Rows: [ all different ] open l_actual for select rownum+1 col_1, rownum+2 col_2, rownum+3 col_3, rownum+4 col_4 from dual connect by level <=2; open l_expected for select rownum+1 col_1, rownum+4 col_4, rownum+2 col_2, rownum+3 col_3 from dual connect by level <=2; --Act - ut3.ut.expect(l_actual).to_equal(l_expected); + ut3.ut.expect(l_actual).to_equal(l_expected).unordered_columns; ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; @@ -791,7 +791,7 @@ Rows: [ 60 differences, showing first 20 ] select 'F' AS GENDER, 'JESSICA' as FIRST_NAME, 'JONES' AS LAST_NAME, 4 as ID, '2345' AS SALARY from dual union all select 'M' AS GENDER, 'LUKE' as FIRST_NAME, 'SKYWALKER' AS LAST_NAME, 2 as ID, '1000' AS SALARY from dual; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).ordered_columns; + ut3.ut.expect(l_actual).to_equal(l_expected); l_expected_message := q'[Actual: refcursor [ count = 4 ] was expected to equal: refcursor [ count = 3 ] Diff: Columns: @@ -828,7 +828,7 @@ Rows: [ 4 differences ] select 'F' AS GENDER, 'JESSICA' as FIRST_NAME, 'JONES' AS LAST_NAME, 4 as ID, '2345' AS SALARY from dual union all select 'M' AS GENDER, 'LUKE' as FIRST_NAME, 'SKYWALKER' AS LAST_NAME, 2 as ID, '1000' AS SALARY from dual; --Act - ut3.ut.expect(l_actual).to_equal(l_expected); + ut3.ut.expect(l_actual).to_equal(l_expected).unordered_columns; l_expected_message := q'[Actual: refcursor [ count = 4 ] was expected to equal: refcursor [ count = 3 ] Diff: Columns: @@ -1051,7 +1051,7 @@ Rows: [ 4 differences ] open l_actual for select '1' , '2' from dual connect by level <=2; open l_expected for select rownum , rownum expected_column_name from dual connect by level <=2; --Act - ut3.ut.expect(l_actual).to_equal(l_expected).ordered_columns; + ut3.ut.expect(l_actual).to_equal(l_expected); l_expected_message := q'[%Actual: refcursor [ count = 2 ] was expected to equal: refcursor [ count = 2 ] %Diff: @@ -1148,7 +1148,7 @@ Rows: [ 4 differences ] open l_expected for select 1 as col_1, 2 as col_2,3 as col_3, 4 as col_4,5 col_5 from dual; open l_actual for select 2 as col_2, 1 as col_1,40 as col_4, 5 as col_5, 30 col_3 from dual; --Act - ut3.ut.expect( l_actual ).to_equal( l_expected ).join_by('COL_1'); + ut3.ut.expect( l_actual ).to_equal( l_expected ).join_by('COL_1').unordered_columns; --Assert l_expected_message := q'[Actual: refcursor [ count = 1 ] was expected to equal: refcursor [ count = 1 ] %Diff: From bd54710e40a43058c5edba47d00a92bbf8949bb1 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Tue, 11 Dec 2018 17:24:37 +0000 Subject: [PATCH 81/83] Adding short-name for unordered columns option UC. --- docs/userguide/expectations.md | 5 +- source/expectations/matchers/ut_equal.tpb | 5 ++ source/expectations/matchers/ut_equal.tps | 1 + .../expectations/ut_expectation_compound.tpb | 11 ++++ .../expectations/ut_expectation_compound.tps | 4 +- .../expectations/test_expectations_cursor.pkb | 64 +++++++++++++++++++ .../expectations/test_expectations_cursor.pks | 12 ++++ 7 files changed, 99 insertions(+), 3 deletions(-) diff --git a/docs/userguide/expectations.md b/docs/userguide/expectations.md index bccc027f8..a1eb1f1dc 100644 --- a/docs/userguide/expectations.md +++ b/docs/userguide/expectations.md @@ -713,7 +713,7 @@ utPLSQL is capable of comparing compound data-types including: - Attributes in nested table and array types are compared as **ordered lists of elements**. If order of attributes in nested table and array differ, expectation will fail. -- Columns in cursors are compared as **ordered list of elements** by default. If order of columns in cursor is not of importance the option has to be passed to enforce column order comparison ` unordered_columns` e.g. +- Columns in cursors are compared as **ordered list of elements** by default. If order of columns in cursor is not of importance the option has to be passed to enforce column order comparison ` unordered_columns` or a short version `uc` e.g. ```sql procedure ut_refcursors1 is @@ -725,7 +725,8 @@ utPLSQL is capable of comparing compound data-types including: open l_actual for select 1 user_id,'s' a_col,'test' username from dual; open l_expected for select 'test' username,'s' a_col,1 user_id from dual; --Act - ut.expect(l_actual).to_equal(l_expected).join_by('USER_ID').unordered_columns; + ut.expect(l_actual).to_equal(l_expected).join_by('USER_ID').unordered_columns(); + ut.expect(l_actual).to_equal(l_expected).join_by('USER_ID').uc(); end; ``` diff --git a/source/expectations/matchers/ut_equal.tpb b/source/expectations/matchers/ut_equal.tpb index 50c6b74a1..000d3a10c 100644 --- a/source/expectations/matchers/ut_equal.tpb +++ b/source/expectations/matchers/ut_equal.tpb @@ -254,6 +254,11 @@ create or replace type body ut_equal as return ( coalesce(join_columns, ut_varchar2_list()) ); end; + member function uc return ut_equal is + begin + return unordered_columns; + end; + member function unordered_columns return ut_equal is l_result ut_equal := self; begin diff --git a/source/expectations/matchers/ut_equal.tps b/source/expectations/matchers/ut_equal.tps index 8278f2ed1..3a065d7c0 100644 --- a/source/expectations/matchers/ut_equal.tps +++ b/source/expectations/matchers/ut_equal.tps @@ -82,6 +82,7 @@ create or replace type ut_equal force under ut_comparison_matcher( overriding member function failure_message(a_actual ut_data_value) return varchar2, overriding member function failure_message_when_negated(a_actual ut_data_value) return varchar2, member function unordered_columns return ut_equal, + member function uc return ut_equal, member function get_ordered_columns return boolean ) not final diff --git a/source/expectations/ut_expectation_compound.tpb b/source/expectations/ut_expectation_compound.tpb index 7e855c2ce..5b8e6e33c 100644 --- a/source/expectations/ut_expectation_compound.tpb +++ b/source/expectations/ut_expectation_compound.tpb @@ -245,5 +245,16 @@ create or replace type body ut_expectation_compound as end if; end; + member function uc return ut_expectation_compound is + l_result ut_expectation_compound; + begin + return unordered_columns; + end; + + member procedure uc(self in ut_expectation_compound) is + begin + unordered_columns; + end; + end; / diff --git a/source/expectations/ut_expectation_compound.tps b/source/expectations/ut_expectation_compound.tps index 12b43a4fd..3cf141047 100644 --- a/source/expectations/ut_expectation_compound.tps +++ b/source/expectations/ut_expectation_compound.tps @@ -50,7 +50,9 @@ create or replace type ut_expectation_compound under ut_expectation( member procedure join_by(self in ut_expectation_compound, a_columns varchar2), member procedure join_by(self in ut_expectation_compound, a_columns ut_varchar2_list), member function unordered_columns return ut_expectation_compound, - member procedure unordered_columns(self in ut_expectation_compound) + member procedure unordered_columns(self in ut_expectation_compound), + member function uc return ut_expectation_compound, + member procedure uc(self in ut_expectation_compound) ) final / diff --git a/test/core/expectations/test_expectations_cursor.pkb b/test/core/expectations/test_expectations_cursor.pkb index ce0b6e0bf..ea3d50363 100644 --- a/test/core/expectations/test_expectations_cursor.pkb +++ b/test/core/expectations/test_expectations_cursor.pkb @@ -319,6 +319,20 @@ create or replace package body test_expectations_cursor is ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + procedure pass_on_diff_column_ord_uc + as + l_expected sys_refcursor; + l_actual sys_refcursor; + begin + --Arrange + open l_expected for select 1 as col_1, 2 as col_2 from dual; + open l_actual for select 2 as col_2, 1 as col_1 from dual; + --Act + ut3.ut.expect( l_actual ).to_equal( l_expected ).uc; + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + procedure fail_on_multi_diff_col_order as l_expected sys_refcursor; @@ -342,6 +356,29 @@ create or replace package body test_expectations_cursor is ut.expect(l_actual_message).to_be_like(l_expected_message); end; + procedure fail_on_multi_diff_col_ord_uc + as + l_expected sys_refcursor; + l_actual sys_refcursor; + l_actual_message varchar2(32767); + l_expected_message varchar2(32767); + begin + --Arrange + open l_expected for select 1 as col_1, 2 as col_2,3 as col_3, 4 as col_4,5 col_5 from dual; + open l_actual for select 2 as col_2, 1 as col_1,40 as col_4, 5 as col_5, 30 col_3 from dual; + --Act + ut3.ut.expect( l_actual ).to_equal( l_expected ).uc; + --Assert + l_expected_message := q'[Actual: refcursor [ count = 1 ] was expected to equal: refcursor [ count = 1 ] +%Diff: +%Rows: [ 1 differences ] +%Row No. 1 - Actual: 4030 +%Row No. 1 - Expected: 34]'; + l_actual_message := ut3.ut_expectation_processor.get_failed_expectations()(1).message; + --Assert + ut.expect(l_actual_message).to_be_like(l_expected_message); + end; + procedure fail_on_different_row_order as l_expected sys_refcursor; @@ -1095,6 +1132,19 @@ Rows: [ 4 differences ] ut.expect(expectations.failed_expectations_data()).to_be_empty(); end; + procedure cursor_unord_compr_success_uc is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select user_id, username from all_users order by username asc; + open l_expected for select username , user_id from all_users order by username desc; + --Act + ut3.ut.expect(l_actual).to_equal(l_expected).unordered().uc(); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; + procedure cursor_unordered_compare_fail is l_actual SYS_REFCURSOR; l_expected SYS_REFCURSOR; @@ -1122,6 +1172,20 @@ Rows: [ 4 differences ] --Assert ut.expect(l_actual_message).to_be_like(l_expected_message); end; + + procedure cursor_joinby_compare_uc is + l_actual SYS_REFCURSOR; + l_expected SYS_REFCURSOR; + begin + --Arrange + open l_actual for select owner, object_id, object_name,object_type from all_objects where owner = user; + open l_expected for select object_id, owner, object_name,object_type from all_objects where owner = user; + + --Act + ut3.ut.expect(l_actual).to_equal(l_expected).join_by('OBJECT_ID').uc(); + --Assert + ut.expect(expectations.failed_expectations_data()).to_be_empty(); + end; procedure cursor_joinby_compare is l_actual SYS_REFCURSOR; diff --git a/test/core/expectations/test_expectations_cursor.pks b/test/core/expectations/test_expectations_cursor.pks index a4db867ae..ea942ddff 100644 --- a/test/core/expectations/test_expectations_cursor.pks +++ b/test/core/expectations/test_expectations_cursor.pks @@ -74,9 +74,15 @@ create or replace package test_expectations_cursor is --%test(Pass when different column ordering is used in cursors) procedure pass_on_different_column_order; + --%test(Pass when different column ordering is used in cursors - shortname) + procedure pass_on_diff_column_ord_uc; + --%test(Fail and highlight diffrence between columns when columns are unordered and different value) procedure fail_on_multi_diff_col_order; + --%test(Fail and highlight diffrence between columns when columns are unordered and different value - shortname) + procedure fail_on_multi_diff_col_ord_uc; + --%test(Gives failure when different row ordering is used in cursors) procedure fail_on_different_row_order; @@ -205,12 +211,18 @@ create or replace package test_expectations_cursor is --%test( Compare cursors using unordered method success) procedure cursor_unorderd_compr_success; + --%test( Compare cursors using unordered method success and unordered columns position) + procedure cursor_unord_compr_success_uc; + --%test( Compare cursors using unordered method failure) procedure cursor_unordered_compare_fail; --%test( Compare cursors join by single key ) procedure cursor_joinby_compare; + --%test( Compare cursors join by single key with unordered columns position using shortname) + procedure cursor_joinby_compare_uc; + --%test(Compare cursors by single key with unordered columns position) procedure cursor_joinby_col_not_ord; From 6f830dc12028512450b654357511f7ade67fb4a1 Mon Sep 17 00:00:00 2001 From: Jacek Gebal Date: Wed, 12 Dec 2018 20:31:06 +0000 Subject: [PATCH 82/83] Minor formatting and warnings fixed --- .../data_values/ut_compound_data_helper.pkb | 52 ++++++++----------- .../expectations/ut_expectation_compound.tpb | 3 +- 2 files changed, 24 insertions(+), 31 deletions(-) diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 8bc556e78..895a7add5 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -173,12 +173,9 @@ create or replace package body ut_compound_data_helper is if l_pk_tab.count <> 0 then l_index:= l_pk_tab.first; loop - if a_data_info.access_path = l_pk_tab(l_index) then - l_sql_stmt := case when a_join_by_stmt is null then null else ' and ' end; - l_sql_stmt := l_sql_stmt ||' a.'||a_col_name||q'[ = ]'||' e.'||a_col_name; - elsif a_data_info.parent_name = l_pk_tab(l_index)then + if l_pk_tab(l_index) in (a_data_info.access_path, a_data_info.parent_name) then --When then table is nested and join is on whole table - l_sql_stmt := case when a_join_by_stmt is null then null else ' and ' end; + l_sql_stmt := case when a_join_by_stmt is null then null else ' and ' end; l_sql_stmt := l_sql_stmt ||' a.'||a_col_name||q'[ = ]'||' e.'||a_col_name; end if; exit when (a_data_info.access_path = l_pk_tab(l_index)) or l_index = l_pk_tab.count; @@ -206,12 +203,9 @@ create or replace package body ut_compound_data_helper is if l_pk_tab.count <> 0 then l_index:= l_pk_tab.first; loop - if a_data_info.access_path = l_pk_tab(l_index) then - l_sql_stmt := case when a_partition_stmt is null then null else ',' end; - l_sql_stmt := l_sql_stmt ||l_alias||a_col_name; - elsif a_data_info.parent_name = l_pk_tab(l_index)then + if l_pk_tab(l_index) in (a_data_info.access_path, a_data_info.parent_name) then --When then table is nested and join is on whole table - l_sql_stmt := case when a_partition_stmt is null then null else ',' end; + l_sql_stmt := case when a_partition_stmt is null then null else ',' end; l_sql_stmt := l_sql_stmt ||l_alias||a_col_name; end if; @@ -261,9 +255,11 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(a_sql_stmt, l_sql_stmt); end; - procedure gen_sql_pieces_out_of_cursor(a_data_info ut_cursor_column_tab,a_pk_table ut_varchar2_list, a_xml_stmt out nocopy clob, - a_select_stmt out nocopy clob ,a_partition_stmt out nocopy clob, a_equal_stmt out nocopy clob, a_join_by_stmt out nocopy clob, - a_not_equal_stmt out nocopy clob) is + procedure gen_sql_pieces_out_of_cursor( + a_data_info ut_cursor_column_tab,a_pk_table ut_varchar2_list, a_xml_stmt out nocopy clob, + a_select_stmt out nocopy clob ,a_partition_stmt out nocopy clob, a_equal_stmt out nocopy clob, a_join_by_stmt out nocopy clob, + a_not_equal_stmt out nocopy clob + ) is l_cursor_info ut_cursor_column_tab := a_data_info; l_partition_tmp clob; l_col_name varchar2(100); @@ -338,13 +334,12 @@ create or replace package body ut_compound_data_helper is function get_join_type(a_inclusion_compare in boolean,a_negated in boolean) return varchar2 is begin - if a_inclusion_compare and not(a_negated) then - return ' right outer join '; - elsif a_inclusion_compare and a_negated then - return ' inner join '; - else - return ' full outer join '; - end if; + return + case + when a_inclusion_compare and not(a_negated) then ' right outer join ' + when a_inclusion_compare and a_negated then ' inner join ' + else ' full outer join ' + end; end; begin @@ -388,10 +383,8 @@ create or replace package body ut_compound_data_helper is if l_not_equal_stmt is not null then ut_utils.append_to_clob(l_compare_sql,' ( '||l_not_equal_stmt||' ) or '); end if; - elsif not a_unordered then - if l_not_equal_stmt is not null then - ut_utils.append_to_clob(l_compare_sql,' ( '||l_not_equal_stmt||' ) or '); - end if; + elsif not a_unordered and l_not_equal_stmt is not null then + ut_utils.append_to_clob(l_compare_sql,' ( '||l_not_equal_stmt||' ) or '); end if; --If its inlcusion we expect a actual set to fully match and have no extra elements over expected @@ -420,8 +413,6 @@ create or replace package body ut_compound_data_helper is a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_join_by_list ut_varchar2_list, a_unordered boolean, a_enforce_column_order boolean := false ) return tt_row_diffs is - l_act_col_filter varchar2(32767); - l_exp_col_filter varchar2(32767); l_act_extract_xpath varchar2(32767):= ut_utils.to_xpath(get_column_extract_path(a_act_cursor_info)); l_exp_extract_xpath varchar2(32767):= ut_utils.to_xpath(get_column_extract_path(a_exp_cursor_info)); l_join_xpath varchar2(32767) := ut_utils.to_xpath(a_join_by_list); @@ -636,8 +627,11 @@ create or replace package body ut_compound_data_helper is end; --Filter out columns from cursor based on include (exists) or exclude (not exists) - function filter_out_cols(a_cursor_info ut_cursor_column_tab, a_current_list ut_varchar2_list,a_include boolean := true) - return ut_cursor_column_tab is + function filter_out_cols( + a_cursor_info ut_cursor_column_tab, + a_current_list ut_varchar2_list, + a_include boolean := true + ) return ut_cursor_column_tab is l_result ut_cursor_column_tab := ut_cursor_column_tab(); l_filter_sql varchar2(32767); begin @@ -690,7 +684,7 @@ create or replace package body ut_compound_data_helper is l_include boolean; begin -- if include and exclude is not null its columns from include minus exclude - -- If inlcude is not null and exclude is null cursor will have only include + -- If include is not null and exclude is null cursor will have only include -- If exclude is not null and include is null cursor will have all except exclude if a_include_xpath.count > 0 and a_exclude_xpath.count > 0 then select col_names bulk collect into l_filtered_set diff --git a/source/expectations/ut_expectation_compound.tpb b/source/expectations/ut_expectation_compound.tpb index 5b8e6e33c..f15911aab 100644 --- a/source/expectations/ut_expectation_compound.tpb +++ b/source/expectations/ut_expectation_compound.tpb @@ -185,7 +185,6 @@ create or replace type body ut_expectation_compound as member procedure unordered(self in ut_expectation_compound) is begin - if ut_utils.int_to_boolean(negated) then self.not_to( treat(matcher as ut_equal).unordered ); else @@ -193,7 +192,7 @@ create or replace type body ut_expectation_compound as end if; end; - member function join_by(a_columns varchar2) return ut_expectation_compound is + member function join_by(a_columns varchar2) return ut_expectation_compound is l_result ut_expectation_compound; begin l_result := self; From 45643e094b45da02642687b0fdf54d8f4ce52713 Mon Sep 17 00:00:00 2001 From: lwasylow Date: Thu, 13 Dec 2018 10:35:11 +0000 Subject: [PATCH 83/83] Tidy up code --- source/core/ut_utils.pks | 4 + .../data_values/ut_compound_data_helper.pkb | 117 ++++++++++-------- .../data_values/ut_compound_data_helper.pks | 3 +- .../data_values/ut_data_value_refcursor.tpb | 12 +- 4 files changed, 82 insertions(+), 54 deletions(-) diff --git a/source/core/ut_utils.pks b/source/core/ut_utils.pks index f6d39638e..26dd1f253 100644 --- a/source/core/ut_utils.pks +++ b/source/core/ut_utils.pks @@ -114,6 +114,10 @@ create or replace package ut_utils authid definer is gc_invalid_package constant pls_integer := -6550; pragma exception_init(ex_invalid_package, -6550); + ex_failure_for_all exception; + gc_failure_for_all constant pls_integer := -24381; + pragma exception_init (ex_failure_for_all, -24381); + gc_max_storage_varchar2_len constant integer := 4000; gc_max_output_string_length constant integer := 4000; gc_max_input_string_length constant integer := gc_max_output_string_length - 2; --we need to remove 2 chars for quotes around string diff --git a/source/expectations/data_values/ut_compound_data_helper.pkb b/source/expectations/data_values/ut_compound_data_helper.pkb index 895a7add5..59e6f9c63 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pkb +++ b/source/expectations/data_values/ut_compound_data_helper.pkb @@ -17,7 +17,7 @@ create or replace package body ut_compound_data_helper is */ g_diff_count integer; - + gc_xpath_extract_reg constant varchar2(50) := '^((/ROW/)|^(//)|^(/\*/))?(.*)'; type t_type_name_map is table of varchar2(128) index by binary_integer; g_type_name_map t_type_name_map; g_anytype_name_map t_type_name_map; @@ -46,8 +46,6 @@ create or replace package body ut_compound_data_helper is function get_columns_diff_ordered(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab) return tt_column_diffs is - l_column_filter varchar2(32767); - l_sql varchar2(32767); l_results tt_column_diffs; begin with @@ -87,8 +85,6 @@ create or replace package body ut_compound_data_helper is function get_columns_diff_unordered(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab) return tt_column_diffs is - l_column_filter varchar2(32767); - l_sql varchar2(32767); l_results tt_column_diffs; begin with @@ -125,11 +121,11 @@ create or replace package body ut_compound_data_helper is function get_columns_diff(a_expected ut_cursor_column_tab, a_actual ut_cursor_column_tab,a_order_enforced boolean := false) return tt_column_diffs is begin - if a_order_enforced then - return get_columns_diff_ordered(a_expected,a_actual); - else - return get_columns_diff_unordered(a_expected,a_actual); - end if; + return + case + when a_order_enforced then get_columns_diff_ordered(a_expected,a_actual) + else get_columns_diff_unordered(a_expected,a_actual) + end; end; function get_pk_value (a_join_by_xpath varchar2,a_item_data xmltype) return clob is @@ -139,8 +135,10 @@ create or replace package body ut_compound_data_helper is return l_pk_value; end; - procedure generate_not_equal_stmt(a_data_info ut_cursor_column, a_pk_table ut_varchar2_list, a_not_equal_stmt in out nocopy clob, - a_col_name varchar2) is + procedure generate_not_equal_stmt( + a_data_info ut_cursor_column, a_pk_table ut_varchar2_list, + a_not_equal_stmt in out nocopy clob, a_col_name varchar2 + ) is l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); l_index integer; l_sql_stmt varchar2(32767); @@ -164,8 +162,10 @@ create or replace package body ut_compound_data_helper is end if; end; - procedure generate_join_by_stmt(a_data_info ut_cursor_column, a_pk_table ut_varchar2_list, a_join_by_stmt in out nocopy clob, - a_col_name varchar2) is + procedure generate_join_by_stmt( + a_data_info ut_cursor_column, a_pk_table ut_varchar2_list, + a_join_by_stmt in out nocopy clob, a_col_name varchar2 + ) is l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); l_index integer; l_sql_stmt varchar2(32767); @@ -192,9 +192,10 @@ create or replace package body ut_compound_data_helper is ut_utils.append_to_clob(a_equal_stmt,l_sql_stmt); end; - procedure generate_partition_stmt(a_data_info ut_cursor_column, a_partition_stmt in out nocopy clob, - a_pk_table in ut_varchar2_list,a_col_name in varchar2,a_alias varchar2 := 'ucd.') is - + procedure generate_partition_stmt( + a_data_info ut_cursor_column, a_partition_stmt in out nocopy clob, + a_pk_table in ut_varchar2_list,a_col_name in varchar2,a_alias varchar2 := 'ucd.' + ) is l_alias varchar2(10) := a_alias; l_pk_tab ut_varchar2_list := coalesce(a_pk_table,ut_varchar2_list()); l_index integer; @@ -284,7 +285,7 @@ create or replace package body ut_compound_data_helper is generate_not_equal_stmt(l_cursor_info(i),a_pk_table,a_not_equal_stmt,l_col_name); end if; end loop; - --Finish parition by + --Finish partition by ut_utils.append_to_clob(a_partition_stmt,l_partition_tmp||' order by '||l_partition_tmp||' ) dup_no '); else --Partition by piece when no data @@ -292,8 +293,10 @@ create or replace package body ut_compound_data_helper is end if; end; - procedure get_act_and_exp_set(a_current_stmt in out nocopy clob, a_partition_stmt clob, a_select_stmt clob, - a_xmltable_stmt clob, a_unordered boolean,a_type varchar2) is + procedure get_act_and_exp_set( + a_current_stmt in out nocopy clob, a_partition_stmt clob, a_select_stmt clob, + a_xmltable_stmt clob, a_unordered boolean,a_type varchar2 + ) is l_temp_string varchar2(32767); l_ut_owner varchar2(250) := ut_utils.ut_owner; begin @@ -409,7 +412,8 @@ create or replace package body ut_compound_data_helper is return l_column_list; end; - function get_rows_diff_by_sql(a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, + function get_rows_diff_by_sql( + a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_join_by_list ut_varchar2_list, a_unordered boolean, a_enforce_column_order boolean := false ) return tt_row_diffs is @@ -601,7 +605,7 @@ create or replace package body ut_compound_data_helper is procedure insert_diffs_result(a_diff_tab t_diff_tab, a_diff_id raw) is begin - forall idx in 1..a_diff_tab.count + forall idx in 1..a_diff_tab.count save exceptions insert into ut_compound_data_diff_tmp ( diff_id, act_item_data, act_data_id, exp_item_data, exp_data_id, item_no, duplicate_no ) values @@ -609,6 +613,9 @@ create or replace package body ut_compound_data_helper is xmlelement( name "ROW", a_diff_tab(idx).act_item_data), a_diff_tab(idx).act_data_id, xmlelement( name "ROW", a_diff_tab(idx).exp_item_data), a_diff_tab(idx).exp_data_id, a_diff_tab(idx).item_no, a_diff_tab(idx).dup_no); + exception + when ut_utils.ex_failure_for_all then + raise_application_error(ut_utils.gc_failure_for_all,'Failure to insert a diff tmp data.'); end; procedure set_rows_diff(a_rows_diff integer) is @@ -651,7 +658,8 @@ create or replace package body ut_compound_data_helper is return l_result; end; - function get_missing_filter_columns(a_cursor_info ut_cursor_column_tab, a_column_filter_list ut_varchar2_list) return ut_varchar2_list is + function get_missing_filter_columns(a_cursor_info ut_cursor_column_tab, a_column_filter_list ut_varchar2_list) + return ut_varchar2_list is l_result ut_varchar2_list := ut_varchar2_list(); begin select fl.column_value @@ -689,20 +697,20 @@ create or replace package body ut_compound_data_helper is if a_include_xpath.count > 0 and a_exclude_xpath.count > 0 then select col_names bulk collect into l_filtered_set from( - select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + select regexp_replace(column_value,gc_xpath_extract_reg,'\5') col_names from table(a_include_xpath) minus - select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + select regexp_replace(column_value,gc_xpath_extract_reg,'\5') col_names from table(a_exclude_xpath) ); l_include := true; elsif a_include_xpath.count > 0 and a_exclude_xpath.count = 0 then - select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + select regexp_replace(column_value,gc_xpath_extract_reg,'\5') col_names bulk collect into l_filtered_set from table(a_include_xpath); l_include := true; elsif a_include_xpath.count = 0 and a_exclude_xpath.count > 0 then - select regexp_replace(column_value,'^((/ROW/)|^(//)|^(/\*/))?(.*)','\5') col_names + select regexp_replace(column_value,gc_xpath_extract_reg,'\5') col_names bulk collect into l_filtered_set from table(a_exclude_xpath); l_include := false; @@ -719,7 +727,8 @@ create or replace package body ut_compound_data_helper is return l_result; end; - function contains_collection (a_cursor_info ut_cursor_column_tab) return number is + function contains_collection (a_cursor_info ut_cursor_column_tab) + return number is l_collection_elements number; begin select count(1) into l_collection_elements from @@ -727,7 +736,8 @@ create or replace package body ut_compound_data_helper is return l_collection_elements; end; - function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list) return ut_cursor_column_tab is + function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_incomparable_cols ut_varchar2_list) + return ut_cursor_column_tab is l_result ut_cursor_column_tab; begin select ut_cursor_column(i.parent_name,i.access_path,i.has_nested_col,i.transformed_name,i.hierarchy_level,i.column_position , @@ -742,22 +752,23 @@ create or replace package body ut_compound_data_helper is end; function getxmlchildren(a_parent_name varchar2,a_cursor_table ut_cursor_column_tab) - return xmltype is - l_result xmltype; - begin - select xmlagg(xmlelement(evalname t.column_name,t.column_type, - getxmlchildren(t.column_name,a_cursor_table))) - into l_result - from table(a_cursor_table) t - where (a_parent_name is not null and parent_name = a_parent_name and hierarchy_level > 1 and column_name is not null) - or (a_parent_name is null and parent_name is null and hierarchy_level = 1 and column_name is not null) - having count(*) > 0; - + return xmltype is + l_result xmltype; + begin + select xmlagg(xmlelement(evalname t.column_name,t.column_type, + getxmlchildren(t.column_name,a_cursor_table))) + into l_result + from table(a_cursor_table) t + where (a_parent_name is not null and parent_name = a_parent_name and hierarchy_level > 1 and column_name is not null) + or (a_parent_name is null and parent_name is null and hierarchy_level = 1 and column_name is not null) + having count(*) > 0; - return l_result; - end; + return l_result; + end; - function is_sql_compare_allowed(a_type_name varchar2) return boolean is + function is_sql_compare_allowed(a_type_name varchar2) + return boolean is + l_assert boolean; begin --clob/blob/xmltype/object/nestedcursor/nestedtable if a_type_name IN (g_type_name_map(dbms_sql.blob_type), @@ -765,18 +776,25 @@ create or replace package body ut_compound_data_helper is g_type_name_map(dbms_sql.bfile_type), g_anytype_name_map(dbms_types.typecode_namedcollection)) then - return false; + l_assert := false; else - return true; + l_assert := true; end if; + return l_assert; end; - function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) return varchar2 is + function get_column_type_desc(a_type_code in integer, a_dbms_sql_desc in boolean) + return varchar2 is begin - return case when a_dbms_sql_desc then g_type_name_map(a_type_code) else g_anytype_name_map(a_type_code) end; + return + case + when a_dbms_sql_desc then g_type_name_map(a_type_code) + else g_anytype_name_map(a_type_code) + end; end; - function get_anytype_members_info( a_anytype anytype ) return t_anytype_members_rec is + function get_anytype_members_info( a_anytype anytype ) + return t_anytype_members_rec is l_result t_anytype_members_rec; begin if a_anytype is not null then @@ -795,7 +813,8 @@ create or replace package body ut_compound_data_helper is return l_result; end; - function get_attr_elem_info( a_anytype anytype, a_pos pls_integer := null ) return t_anytype_elem_info_rec is + function get_attr_elem_info( a_anytype anytype, a_pos pls_integer := null ) + return t_anytype_elem_info_rec is l_result t_anytype_elem_info_rec; begin if a_anytype is not null then diff --git a/source/expectations/data_values/ut_compound_data_helper.pks b/source/expectations/data_values/ut_compound_data_helper.pks index de988e489..79c90f4c5 100644 --- a/source/expectations/data_values/ut_compound_data_helper.pks +++ b/source/expectations/data_values/ut_compound_data_helper.pks @@ -99,7 +99,8 @@ create or replace package ut_compound_data_helper authid definer is a_max_rows integer, a_exclude_xpath varchar2, a_include_xpath varchar2 ) return tt_row_diffs; - function get_rows_diff_by_sql(a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, + function get_rows_diff_by_sql( + a_act_cursor_info ut_cursor_column_tab,a_exp_cursor_info ut_cursor_column_tab, a_expected_dataset_guid raw, a_actual_dataset_guid raw, a_diff_id raw, a_join_by_list ut_varchar2_list, a_unordered boolean, a_enforce_column_order boolean := false ) return tt_row_diffs; diff --git a/source/expectations/data_values/ut_data_value_refcursor.tpb b/source/expectations/data_values/ut_data_value_refcursor.tpb index 10be342ea..2ac8b99ec 100644 --- a/source/expectations/data_values/ut_data_value_refcursor.tpb +++ b/source/expectations/data_values/ut_data_value_refcursor.tpb @@ -16,7 +16,8 @@ create or replace type body ut_data_value_refcursor as limitations under the License. */ - constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) return self as result is + constructor function ut_data_value_refcursor(self in out nocopy ut_data_value_refcursor, a_value sys_refcursor) + return self as result is begin init(a_value); return; @@ -122,7 +123,9 @@ create or replace type body ut_data_value_refcursor as return l_result_string; end; - member function diff( a_other ut_data_value, a_unordered boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list() ) return varchar2 is + member function diff( + a_other ut_data_value, a_unordered boolean := false, a_join_by_list ut_varchar2_list:=ut_varchar2_list() + ) return varchar2 is l_result clob; l_results ut_utils.t_clob_tab := ut_utils.t_clob_tab(); l_result_string varchar2(32767); @@ -170,7 +173,9 @@ create or replace type body ut_data_value_refcursor as return l_message; end; - function remove_incomparable_cols( a_cursor_details ut_cursor_column_tab,a_column_diffs ut_compound_data_helper.tt_column_diffs) return ut_cursor_column_tab is + function remove_incomparable_cols( + a_cursor_details ut_cursor_column_tab,a_column_diffs ut_compound_data_helper.tt_column_diffs + ) return ut_cursor_column_tab is l_incomparable_cols ut_varchar2_list := ut_varchar2_list(); l_filter_out ut_cursor_column_tab; begin @@ -186,7 +191,6 @@ create or replace type body ut_data_value_refcursor as function get_diff_message (a_row_diff ut_compound_data_helper.t_row_diffs,a_is_unordered boolean) return varchar2 is begin - if a_is_unordered then if a_row_diff.pk_value is not null then return ' PK '||a_row_diff.pk_value||' - '||rpad(a_row_diff.diff_type,10)||a_row_diff.diffed_row;