Skip to content

Commit

Permalink
chore: Add sample files using DVT for object reconcilliation (#1359)
Browse files Browse the repository at this point in the history
* chore: Add sample files using DVT for object reconcilliation

* Update samples/object_comparisons/README.md

Co-authored-by: Helen Cristina <[email protected]>

* Update samples/object_comparisons/reconcile.sh

Co-authored-by: Helen Cristina <[email protected]>

---------

Co-authored-by: Helen Cristina <[email protected]>
  • Loading branch information
nj1973 and helensilva14 committed Dec 2, 2024
1 parent f4f537d commit 973ad63
Show file tree
Hide file tree
Showing 16 changed files with 254 additions and 0 deletions.
66 changes: 66 additions & 0 deletions samples/object_comparisons/README.md

Large diffs are not rendered by default.

15 changes: 15 additions & 0 deletions samples/object_comparisons/oracle/cons_fk.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
SELECT LOWER(owner) AS schema
, LOWER(table_name) AS tablename
, LOWER(columns) AS columns
FROM (
SELECT c.owner,c.table_name,c.constraint_name
, LISTAGG(LOWER(cl.column_name),',') WITHIN GROUP (ORDER BY cl.position) AS columns
FROM all_constraints c
INNER JOIN all_cons_columns cl ON (cl.owner = c.owner
AND cl.constraint_name = c.constraint_name
AND cl.table_name = c.table_name)
WHERE c.constraint_type = 'R'
AND c.table_name NOT LIKE 'DR$%' AND c.table_name NOT LIKE 'BIN$%' AND c.table_name NOT LIKE 'MLOG$%'
AND c.owner NOT IN ('SYS','SYSTEM','DBSNMP','DVSYS','MDSYS','OJVMSYS','OLAPSYS','WMSYS','XDB')
GROUP BY c.owner,c.table_name,c.constraint_name
)
10 changes: 10 additions & 0 deletions samples/object_comparisons/oracle/cons_nn.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
SELECT LOWER(t.owner) AS schema
, LOWER(t.table_name) AS tablename
, LOWER(c.column_name) AS columns
FROM all_tables t
INNER JOIN all_tab_columns c ON (t.owner = c.owner AND t.table_name = c.table_name)
WHERE (t.table_name NOT LIKE 'DR%' AND t.table_name NOT LIKE 'BIN$%' AND t.table_name NOT LIKE 'MLOG$%')
AND NOT EXISTS (SELECT mview_name FROM all_mviews WHERE owner = t.table_name AND mview_name = t.table_name)
AND t.temporary != 'Y'
AND t.owner NOT IN ('SYS','SYSTEM','DBSNMP','DVSYS','MDSYS','OJVMSYS','OLAPSYS','WMSYS','XDB')
AND c.nullable = 'N'
15 changes: 15 additions & 0 deletions samples/object_comparisons/oracle/cons_pk.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
SELECT LOWER(owner) AS schema
, LOWER(table_name) AS tablename
, LOWER(columns) AS columns
FROM (
SELECT c.owner,c.table_name,c.constraint_name
, LISTAGG(LOWER(cl.column_name),',') WITHIN GROUP (ORDER BY cl.position) AS columns
FROM all_constraints c
INNER JOIN all_cons_columns cl ON (cl.owner = c.owner
AND cl.constraint_name = c.constraint_name
AND cl.table_name = c.table_name)
WHERE c.constraint_type = 'P'
AND c.table_name NOT LIKE 'DR$%' AND c.table_name NOT LIKE 'BIN$%' AND c.table_name NOT LIKE 'MLOG$%'
AND c.owner NOT IN ('SYS','SYSTEM','DBSNMP','DVSYS','MDSYS','OJVMSYS','OLAPSYS','WMSYS','XDB')
GROUP BY c.owner,c.table_name,c.constraint_name
)
4 changes: 4 additions & 0 deletions samples/object_comparisons/oracle/sequences.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
SELECT LOWER(sequence_owner) AS schema
, LOWER(sequence_name) AS name
FROM all_sequences
WHERE sequence_owner NOT IN ('SYS','SYSTEM','DBSNMP','DVSYS','MDSYS','OJVMSYS','OLAPSYS','WMSYS','XDB')
8 changes: 8 additions & 0 deletions samples/object_comparisons/oracle/tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
SELECT LOWER(t.owner) AS schema
, LOWER(t.table_name) AS name
, SUBSTR(t.partitioned,1,1) AS partitioned
FROM all_tables t
WHERE (t.table_name NOT LIKE 'DR%' AND t.table_name NOT LIKE 'BIN$%' AND t.table_name NOT LIKE 'MLOG$%')
AND NOT EXISTS (SELECT mview_name FROM all_mviews WHERE owner = t.table_name AND mview_name = t.table_name)
AND t.temporary != 'Y'
AND t.owner NOT IN ('SYS','SYSTEM','DBSNMP','DVSYS','MDSYS','OJVMSYS','OLAPSYS','WMSYS','XDB')
5 changes: 5 additions & 0 deletions samples/object_comparisons/oracle/triggers.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
SELECT owner AS schema
, trigger_name AS name
, table_name AS tablename
FROM all_triggers
WHERE owner NOT IN ('SYS','SYSTEM','DBSNMP','DVSYS','MDSYS','OJVMSYS','OLAPSYS','WMSYS','XDB')
4 changes: 4 additions & 0 deletions samples/object_comparisons/oracle/views.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
SELECT LOWER(owner) AS schema
, LOWER(view_name) AS name
FROM all_views
WHERE owner NOT IN ('SYS','SYSTEM','DBSNMP','DVSYS','MDSYS','OJVMSYS','OLAPSYS','WMSYS','XDB')
16 changes: 16 additions & 0 deletions samples/object_comparisons/postgres/cons_fk.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
SELECT schema,tablename,columns
FROM (
SELECT nsp.nspname::text AS schema
, cls.relname::text AS tablename
, cons.conname::text AS name
, string_agg(col.attname,',' ORDER BY attnum) AS columns
FROM pg_constraint AS cons
INNER JOIN pg_class AS cls ON (cons.conrelid = cls.oid)
INNER JOIN pg_namespace AS nsp ON (nsp.oid = cls.relnamespace)
INNER JOIN pg_attribute AS col ON (col.attrelid = cons.conrelid AND attnum = ANY(cons.conkey))
WHERE cons.contype = 'f'
AND nsp.nspname::text NOT IN ('pg_catalog','pg_toast')
GROUP BY nsp.nspname::text
, cls.relname::text
, cons.conname::text
) q
9 changes: 9 additions & 0 deletions samples/object_comparisons/postgres/cons_nn.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
SELECT nsp.nspname::text AS schema
, cls.relname::text AS tablename
, att.attname::text AS columns
FROM pg_class cls
JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace
JOIN pg_attribute att ON att.attrelid = cls.oid
WHERE nsp.nspname NOT IN ('pg_catalog','pg_toast')
AND att.attnotnull
AND att.attnum >= 1
16 changes: 16 additions & 0 deletions samples/object_comparisons/postgres/cons_pk.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
SELECT schema,tablename,columns
FROM (
SELECT nsp.nspname::text AS schema
, cls.relname::text AS tablename
, ind.indexrelid::text AS name
, string_agg(col.attname,',' ORDER BY attnum) AS columns
FROM pg_index ind
INNER JOIN pg_class AS cls ON (ind.indrelid = cls.oid)
INNER JOIN pg_namespace AS nsp ON (nsp.oid = cls.relnamespace)
INNER JOIN pg_attribute AS col ON (col.attrelid = ind.indrelid AND col.attnum = ANY(ind.indkey))
WHERE ind.indisprimary
AND nsp.nspname::text NOT IN ('pg_catalog','pg_toast')
GROUP BY nsp.nspname::text
, cls.relname::text
, ind.indexrelid::text
) q
4 changes: 4 additions & 0 deletions samples/object_comparisons/postgres/sequences.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
SELECT sequence_schema::text AS schema
, sequence_name::text AS name
FROM information_schema.sequences
WHERE sequence_schema::text NOT IN ('pg_catalog','pg_toast')
7 changes: 7 additions & 0 deletions samples/object_comparisons/postgres/tables.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
SELECT nsp.nspname::text AS schema
, cls.relname::text AS name
, CASE WHEN relispartition THEN 'YES' ELSE 'N' END AS partitioned
FROM pg_class cls
JOIN pg_namespace nsp ON nsp.oid = cls.relnamespace
WHERE nsp.nspname NOT IN ('pg_catalog','pg_toast')
AND cls.relkind = 'r';
5 changes: 5 additions & 0 deletions samples/object_comparisons/postgres/triggers.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
SELECT trigger_schema::text AS schema
, trigger_name::text AS name
, event_object_table::text AS tablename
FROM information_schema.triggers
WHERE trigger_schema::text NOT IN ('pg_catalog','pg_toast')
4 changes: 4 additions & 0 deletions samples/object_comparisons/postgres/views.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
SELECT schemaname::text AS schema
, viewname::text AS name
FROM pg_views
WHERE schemaname::text NOT IN ('pg_catalog','pg_toast')
66 changes: 66 additions & 0 deletions samples/object_comparisons/reconcile.sh
Original file line number Diff line number Diff line change
@@ -0,0 +1,66 @@
#!/bin/bash
# Copyright 2024 Google LLC
#
# 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.


function show_usage {
echo 'Usage: $0 <source-sql-directory> <target-sql-directory> [optional-file-name]'
}

if [[ "$1" = "-h" ]] || [[ "$1" = "--help" ]];then
show_usage
exit 0
fi

if [[ -z "$2" ]];then
show_usage
exit 1
fi

SOURCE_DIR=$1
TARGET_DIR=$2

if [[ -n "$3" ]];then
FILES=$3
else
FILES=$(ls -1 ${SOURCE_DIR})
fi

if [[ $? != 0 ]];then
echo "Error listing files in directory: ${SOURCE_DIR}"
exit 1
fi

SOURCE_CONN="ora_conn"
TARGET_CONN="pg_conn"
SCHEMA="pso_data_validator"

for FILE in $FILES;do
echo "Processing file: ${FILE}"
echo "cons_pk.sql cons_fk.sql cons_nn.sql" | grep -q -w ${FILE}
if [[ $? = 0 ]];then
KEYS="schema,tablename,columns"
else
KEYS="schema,name"
fi
if [[ ! -f "${TARGET_DIR}/${FILE}" ]];then
echo "Skipping file because it does not exist in ${TARGET_DIR}"
continue
fi
data-validation validate custom-query row -sc=${SOURCE_CONN} -tc=${TARGET_CONN} \
-sqf="${SOURCE_DIR}/${FILE}" -tqf="${TARGET_DIR}/${FILE}" \
--filters="schema = '${SCHEMA}'" \
--primary-keys=${KEYS} --concat='*' \
--filter-status=fail
done

0 comments on commit 973ad63

Please sign in to comment.