Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
79 changes: 79 additions & 0 deletions docs/userguide/advanced_data_comparison.md
Original file line number Diff line number Diff line change
Expand Up @@ -126,6 +126,85 @@ end;

```

Example of `include / exclude` for anydata.convertCollection

```plsql
create or replace type person as object(
name varchar2(100),
age integer
)
/
create or replace type people as table of person
/

create or replace package ut_anydata_inc_exc IS

--%suite(Anydata)

--%test(Anydata include)
procedure ut_anydata_test_inc;

--%test(Anydata exclude)
procedure ut_anydata_test_exc;

--%test(Fail on age)
procedure ut_fail_anydata_test;

end ut_anydata_inc_exc;
/

create or replace package body ut_anydata_inc_exc IS

procedure ut_anydata_test_inc IS
l_actual people := people(person('Matt',45));
l_expected people :=people(person('Matt',47));
begin
ut3.ut.expect(anydata.convertCollection(l_actual)).to_equal(anydata.convertCollection(l_expected)).include('NAME');
end;

procedure ut_anydata_test_exc IS
l_actual people := people(person('Matt',45));
l_expected people :=people(person('Matt',47));
begin
--Arrange
ut3.ut.expect(anydata.convertCollection(l_actual)).to_equal(anydata.convertCollection(l_expected)).exclude('AGE');
end;

procedure ut_fail_anydata_test IS
l_actual people := people(person('Matt',45));
l_expected people :=people(person('Matt',47));
begin
--Arrange
ut3.ut.expect(anydata.convertCollection(l_actual)).to_equal(anydata.convertCollection(l_expected)).include('AGE');
end;

end ut_anydata_inc_exc;
/

```

will result in :

```sql
Anydata
Anydata include [.044 sec]
Anydata exclude [.035 sec]
Fail on age [.058 sec] (FAILED - 1)

Failures:

1) ut_fail_anydata_test
Actual: ut3.people [ count = 1 ] was expected to equal: ut3.people [ count = 1 ]
Diff:
Rows: [ 1 differences ]
Row No. 1 - Actual: <AGE>45</AGE>
Row No. 1 - Expected: <AGE>47</AGE>
```



Example of exclude

Only the columns 'RN', "A_Column" will be compared. Column 'SOME_COL' is excluded.

This option can be useful in scenarios where you need to narrow-down the scope of test so that the test is only focused on very specific data.
Expand Down
25 changes: 25 additions & 0 deletions source/core/ut_utils.pkb
Original file line number Diff line number Diff line change
Expand Up @@ -824,5 +824,30 @@ create or replace package body ut_utils is
return l_result;
end;

function add_prefix(a_list ut_varchar2_list, a_prefix varchar2, a_connector varchar2 := '/') return ut_varchar2_list is
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

How about having add_prefix function for individual elements to avoid duplicating the below logic in 3 places:

        case 
          when self.is_anydata = 1 then
            l_prefix||'/'||trim (leading '/' from fl.column_value)
          else
            fl.column_value
          end

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

good catch

Copy link
Member Author

@lwasylow lwasylow May 24, 2019

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Actually that causes an issue due to SQL context switch and min grant user.
We will need to grant execute to public and get a public synonym on utils.

l_result ut_varchar2_list := ut_varchar2_list();
l_idx binary_integer;
begin
if a_prefix is not null then
l_idx := a_list.first;
while l_idx is not null loop
l_result.extend;
l_result(l_idx) := add_prefix(a_list(l_idx), a_prefix, a_connector);
l_idx := a_list.next(l_idx);
end loop;
end if;
return l_result;
end;

function add_prefix(a_item varchar2, a_prefix varchar2, a_connector varchar2 := '/') return varchar2 is
begin
return a_prefix||a_connector||trim(leading a_connector from a_item);
end;

function strip_prefix(a_item varchar2, a_prefix varchar2, a_connector varchar2 := '/') return varchar2 is
begin
return regexp_replace(a_item,a_prefix||a_connector);
end;

end ut_utils;
/
9 changes: 9 additions & 0 deletions source/core/ut_utils.pks
Original file line number Diff line number Diff line change
Expand Up @@ -404,5 +404,14 @@ create or replace package ut_utils authid definer is
*/
function to_cdata(a_clob clob) return clob;

/**
* Add prefix word to elements of list
*/
function add_prefix(a_list ut_varchar2_list, a_prefix varchar2, a_connector varchar2 := '/') return ut_varchar2_list;

function add_prefix(a_item varchar2, a_prefix varchar2, a_connector varchar2 := '/') return varchar2;

function strip_prefix(a_item varchar2, a_prefix varchar2, a_connector varchar2 := '/') return varchar2;

end ut_utils;
/
15 changes: 13 additions & 2 deletions source/expectations/data_values/ut_compound_data_helper.pkb
Original file line number Diff line number Diff line change
Expand Up @@ -335,6 +335,7 @@ create or replace package body ut_compound_data_helper is
l_not_equal_stmt clob;
l_where_stmt clob;
l_ut_owner varchar2(250) := ut_utils.ut_owner;
l_join_by_list ut_varchar2_list;

function get_join_type(a_inclusion_compare in boolean,a_negated in boolean) return varchar2 is
begin
Expand All @@ -356,12 +357,22 @@ create or replace package body ut_compound_data_helper is
end;

begin
/**
* We already estabilished cursor equality so now we add anydata root if we compare anydata
* to join by.
*/
l_join_by_list :=
case
when a_other is of (ut_data_value_anydata) then ut_utils.add_prefix(a_join_by_list, a_other.cursor_details.get_root)
else a_join_by_list
end;

dbms_lob.createtemporary(l_compare_sql, true);
--Initiate a SQL template with placeholders
ut_utils.append_to_clob(l_compare_sql, g_compare_sql_template);
--Generate a pieceso of dynamic SQL that will substitute placeholders
gen_sql_pieces_out_of_cursor(
a_other.cursor_details.cursor_columns_info, a_join_by_list, a_unordered,
a_other.cursor_details.cursor_columns_info, l_join_by_list, a_unordered,
l_xmltable_stmt, l_select_stmt, l_partition_stmt, l_join_on_stmt,
l_not_equal_stmt
);
Expand All @@ -374,7 +385,7 @@ create or replace package body ut_compound_data_helper is
l_compare_sql := replace(l_compare_sql,'{:join_type:}',get_join_type(a_inclusion_type,a_is_negated));
l_compare_sql := replace(l_compare_sql,'{:join_condition:}',l_join_on_stmt);

if l_not_equal_stmt is not null and ((a_join_by_list.count > 0 and not a_is_negated) or (not a_unordered)) then
if l_not_equal_stmt is not null and ((l_join_by_list.count > 0 and not a_is_negated) or (not a_unordered)) then
ut_utils.append_to_clob(l_where_stmt,' ( '||l_not_equal_stmt||' ) or ');
end if;
--If its inclusion we expect a actual set to fully match and have no extra elements over expected
Expand Down
3 changes: 2 additions & 1 deletion source/expectations/data_values/ut_cursor_column.tpb
Original file line number Diff line number Diff line change
Expand Up @@ -26,7 +26,8 @@ create or replace type body ut_cursor_column as
self.xml_valid_name
else
a_access_path||'/'||self.xml_valid_name
end; --Access path used for incldue exclude eg/ TEST_DUMMY_OBJECT/VARCHAR2
end; --Access path used for XMLTABLE query
self.filter_path := '/'||self.access_path; --Filter path will differ from access path in anydata type
self.transformed_name := case when length(self.xml_valid_name) > 30 then
'"'||ut_compound_data_helper.get_fixed_size_hash(self.parent_name||self.xml_valid_name)||'"'
when self.parent_name is null then
Expand Down
3 changes: 2 additions & 1 deletion source/expectations/data_values/ut_cursor_column.tps
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
create or replace type ut_cursor_column force authid current_user as object (
create or replace type ut_cursor_column authid current_user as object (
/*
utPLSQL - Version 3
Copyright 2016 - 2018 utPLSQL Project
Expand All @@ -17,6 +17,7 @@ create or replace type ut_cursor_column force authid current_user as object (
*/
parent_name varchar2(4000),
access_path varchar2(4000),
filter_path varchar2(4000),
display_path varchar2(4000),
has_nested_col number(1,0),
transformed_name varchar2(2000),
Expand Down
33 changes: 28 additions & 5 deletions source/expectations/data_values/ut_cursor_details.tpb
Original file line number Diff line number Diff line change
Expand Up @@ -96,6 +96,7 @@ create or replace type body ut_cursor_details as
l_hierarchy_level integer := 1;
begin
self.cursor_columns_info := ut_cursor_column_tab();
self.is_anydata := 0;
dbms_sql.describe_columns3(a_cursor_number, l_columns_count, l_columns_desc);

/**
Expand Down Expand Up @@ -147,12 +148,13 @@ create or replace type body ut_cursor_details as
member function get_missing_join_by_columns( a_expected_columns ut_varchar2_list ) return ut_varchar2_list is
l_result ut_varchar2_list;
begin
--regexp_replace(c.access_path,'^\/?([^\/]+\/){1}')
select fl.column_value
bulk collect into l_result
from table(a_expected_columns) fl
where not exists (
select 1 from table(self.cursor_columns_info) c
where regexp_like(c.access_path, '^'||fl.column_value||'($|/.*)')
where regexp_like(c.filter_path,'^/?'||fl.column_value||'($|/.*)' )
)
order by fl.column_value;
return l_result;
Expand Down Expand Up @@ -181,8 +183,9 @@ create or replace type body ut_cursor_details as
bulk collect into l_result.cursor_columns_info
from table(self.cursor_columns_info) x
where exists(
select 1 from included_columns f where regexp_like( x.access_path, '^/?'||f.col_names||'($|/.*)' )
);
select 1 from included_columns f where regexp_like(x.filter_path,'^/?'||f.col_names||'($|/.*)' )
)
or x.hierarchy_level = case when self.is_anydata = 1 then 1 else 0 end ;
end if;
elsif a_match_options.exclude.items.count > 0 then
with excluded_columns as (
Expand All @@ -193,7 +196,7 @@ create or replace type body ut_cursor_details as
bulk collect into l_result.cursor_columns_info
from table(self.cursor_columns_info) x
where not exists(
select 1 from excluded_columns f where regexp_like( '/'||x.access_path, '^/?'||f.col_names||'($|/.*)' )
select 1 from excluded_columns f where regexp_like(x.filter_path,'^/?'||f.col_names||'($|/.*)' )
);
end if;

Expand Down Expand Up @@ -226,8 +229,28 @@ create or replace type body ut_cursor_details as
from table(self.cursor_columns_info) t
where (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;

member function get_root return varchar2 is
l_root varchar2(250);
begin
if self.cursor_columns_info.count > 0 then
select x.access_path into l_root from table(self.cursor_columns_info) x
where x.hierarchy_level = 1;
else
l_root := null;
end if;
return l_root;
end;

member procedure strip_root_from_anydata(self in out nocopy ut_cursor_details) is
l_root varchar2(250) := get_root();
begin
self.is_anydata := 1;
for i in 1..cursor_columns_info.count loop
self.cursor_columns_info(i).filter_path := '/'||ut_utils.strip_prefix(self.cursor_columns_info(i).access_path,l_root);
end loop;
end;
end;
/
12 changes: 8 additions & 4 deletions source/expectations/data_values/ut_cursor_details.tps
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
create or replace type ut_cursor_details force authid current_user as object (
create or replace type ut_cursor_details authid current_user as object (
/*
utPLSQL - Version 3
Copyright 2016 - 2018 utPLSQL Project
Expand All @@ -17,6 +17,8 @@ create or replace type ut_cursor_details force authid current_user as object (
*/
cursor_columns_info ut_cursor_column_tab,

/*if type is anydata we need to skip level 1 on joinby / inlude / exclude as its artificial cursor*/
is_anydata 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
Expand All @@ -29,9 +31,11 @@ create or replace type ut_cursor_details force authid current_user as object (
a_level in integer,
a_access_path in varchar2
),
member function contains_collection return boolean,
member function get_missing_join_by_columns( a_expected_columns ut_varchar2_list ) return ut_varchar2_list,
member function contains_collection return boolean,
member function get_missing_join_by_columns( a_expected_columns ut_varchar2_list ) return ut_varchar2_list,
member procedure filter_columns(self in out nocopy ut_cursor_details, a_match_options ut_matcher_options),
member function get_xml_children(a_parent_name varchar2 := null) return xmltype
member function get_xml_children(a_parent_name varchar2 := null) return xmltype,
member function get_root return varchar2,
member procedure strip_root_from_anydata(self in out nocopy ut_cursor_details)
)
/
3 changes: 1 addition & 2 deletions source/expectations/data_values/ut_data_value_anydata.tpb
Original file line number Diff line number Diff line change
Expand Up @@ -61,8 +61,6 @@ create or replace type body ut_data_value_anydata as

member procedure init(self in out nocopy ut_data_value_anydata, a_value anydata) is
l_refcursor sys_refcursor;
l_ctx number;
l_ut_owner varchar2(250) := ut_utils.ut_owner;
cursor_not_open exception;
l_cursor_number number;
l_anydata_sql varchar2(32767);
Expand All @@ -84,6 +82,7 @@ create or replace type body ut_data_value_anydata as
self.extract_cursor(l_refcursor);
l_cursor_number := dbms_sql.to_cursor_number(l_refcursor);
self.cursor_details := ut_cursor_details(l_cursor_number);
self.cursor_details.strip_root_from_anydata;
dbms_sql.close_cursor(l_cursor_number);
elsif not l_refcursor%isopen then
raise cursor_not_open;
Expand Down
10 changes: 8 additions & 2 deletions source/expectations/data_values/ut_data_value_refcursor.tpb
Original file line number Diff line number Diff line change
Expand Up @@ -250,8 +250,14 @@ create or replace type body ut_data_value_refcursor as
if l_diff_row_count > 0 then
l_row_diffs := ut_compound_data_helper.get_rows_diff_by_sql(
l_self_cols, l_other_cols, l_self.data_id, l_other.data_id,
l_diff_id, a_match_options.join_by.items, a_match_options.unordered,
a_match_options.ordered_columns(), self.extract_path
l_diff_id,
case
when
l_self.cursor_details.is_anydata = 1 then ut_utils.add_prefix(a_match_options.join_by.items, l_self.cursor_details.get_root)
else
a_match_options.join_by.items
end,
a_match_options.unordered,a_match_options.ordered_columns(), self.extract_path
);
l_message := chr(10)
||'Rows: [ ' || l_diff_row_count ||' differences'
Expand Down
Loading