1.09 TRANSFORMATIONS

9.1 List All Transformations used in Folder Level

				
					SELECT DISTINCT SUBJECT_AREA AS
FOLDER_NAME,
PARENT_WIDGET_NAME AS TRANS_NAME,
WIDGET_TYPE_NAME AS TRANS_TYPE
FROM REP_ALL_TRANSFORMS
ORDER BY 1,2,3
				
			

9.2 List all Transformations with Transformation type

				
					SELECT DISTINCT SUBJECT_AREA,
  WIDGET_TYPE_NAME,
  PARENT_WIDGET_NAME
FROM REP_ALL_TRANSFORMS
WHERE WIDGET_TYPE_NAME ='Aggregator'
ORDER BY 1,2
				
			
Aggregator
App Multi-Group Source Qualifier
Application Source Qualifier
Custom Transformation
Expression
Filter
Input Transformation
Joiner
Lookup Procedure
Normalizer
Output Transformation
Rank
Router
Sequence
Sorter
Source Qualifier
Stored Procedure
Transaction Control
Update Strategy
XML Source Qualifier

9.3 List Sequence Generator Value

				
					SELECT a.attr_value AS current_value, b.WIDGET_NAME AS Transformation_name
FROM rep_widget_attr a, REP_ALL_TRANSFORMS b
WHEREa.attr_id = 4
AND a.widget_id IN (SELECT widget_id
FROM REP_ALL_TRANSFORMS
WHERE widget_type_name LIKE 'Sequence')
AND a.widget_id = b.widget_id
				
			

9.4 List of Sequence transformations

				
					SELECT DISTINCT SUBJECT_AREA, PARENT_WIDGET_NAME FROM REP_ALL_TRANSFORMS WHERE WIDGET_TYPE_NAME ='Sequence' ORDER BY 1,2


select distinct
b.subj_name,
c.instance_name,
a.mapping_name
from
opb_mapping
a,
opb_subject
b,
opb_widget_inst
c
where
a.subject_id = b.subj_id
and a.mapping_id = c.mapping_id
and c.widget_type = 7
and a.is_visible = 1
and a.is_valid = 1
order by 1,2,3
				
			

9.5 List of filter transformations

				
					SELECT SUBSTR(WIDGET_NAME,1,3),
COUNT(WIDGET_NAME)
FROM REP_ALL_TRANSFORMS
WHERE WIDGET_TYPE_NAME = 'Filter'
GROUP BY SUBSTR(WIDGET_NAME,1,3)
				
			

9.6 List of tables used as lookups

				
					SELECT DISTINCT
B.PARENT_SUBJECT_AREA AS FOLDER_NAME,
C.ATTR_VALUE AS
TABLE_NAME,A.INSTANCE_NAME AS
TRANSFORMATION_NAME, A.WIDGET_TYPE_NAME AS
TRANSFORMATION_TYPE,B.MAPPING_NAME
FROM
REP_WIDGET_INST
A INNER JOIN REP_ALL_MAPPINGS B ON A.MAPPING_ID = B.MAPPING_ID
INNER JOIN
REP_WIDGET_ATTR
C ON A.WIDGET_ID = C.WIDGET_ID
WHERE
C.ATTR_DESCRIPTION LIKE 'Lookup
source table'
ORDER BY 1,2,3,4,5
				
			

9.7 List of transformations using sql overrides

				
					SELECT DISTINCT
d.subject_area AS Folder, d.mapping_name, a.widget_type_name AS Transformation_Type,
a.instance_name as Transformation_Name, b.attr_name, b.attr_value, c.session_name 
FROM
REP_WIDGET_INST
a, REP_WIDGET_ATTR b, REP_LOAD_SESSIONS c, REP_ALL_MAPPINGS d
WHERE b.widget_id = a. widget_id
AND b.widget_type = a. widget_type
AND b.widget_type in (3, 11)
AND c.mapping_id = a.mapping_id
AND d.mapping_id = a.mapping_id
AND b.attr_id= 1
AND b.attr_datatype=2 and b.attr_type=3
ORDER BY d.subject_area, d.mapping_name


SELECT
DISTINCT
C.SUBJECT_AREA,
C.MAPPING_NAME,C.MAPPING_ID,
B.WIDGET_TYPE_NAME
AS TRANSFORMATION_TYPE,
B.INSTANCE_NAME
AS TRANSFORMATION_NAME,
X.SQL_SQUERY
FROM
(SELECT
A.ATTR_NAME,A.ATTR_VALUE AS SQL_SQUERY,A.WIDGET_ID,A.MAPPING_ID FROM
REP_WIDGET_ATTR A
WHERE
WIDGET_TYPE IN (3,11)
AND
A.ATTR_ID= 1
AND
A.ATTR_VALUE IS NOT NULL) X,
REP_WIDGET_INST
B,
REP_ALL_MAPPINGS
C
WHERE

X.WIDGET_ID
= B. WIDGET_ID
AND
X.MAPPING_ID = C.MAPPING_ID
ORDER
BY 1,2,3
				
			

9.8 List all transformations

				
					SELECT DISTINCT version_subject.subject_area "FOLDER_NAME",
version_props.object_name "OBJECT_NAME",
CASE
WHEN version_props.object_type = 1 THEN 'Source Definition'ELSE CASE
WHEN version_props.object_type = 2 THEN 'Target Definition'ELSE CASE
WHEN version_props.object_type = 3 THEN 'Source Qualifier'ELSE CASE
WHEN version_props.object_type = 4 THEN 'Update Strategy'ELSE CASE
WHEN version_props.object_type = 5 THEN 'Expression'ELSE CASE
WHEN version_props.object_type = 6 THEN 'Stored Procedure'ELSE CASE
WHEN version_props.object_type = 7 THEN 'Sequence'ELSE CASE
WHEN version_props.object_type = 8 THEN 'External Procedure'ELSE CASE
WHEN version_props.object_type = 9 THEN 'Aggregator'ELSE CASE
WHEN version_props.object_type = 10 THEN 'Filter'ELSE CASE
WHEN version_props.object_type = 11 THEN 'Lookup Procedure'ELSE CASE
WHEN version_props.object_type = 12 THEN 'Joiner'ELSE CASE
WHEN version_props.object_type = 13 THEN 'Procedure'ELSE CASE
WHEN version_props.object_type = 14 THEN 'Normalizer'ELSE CASE
WHEN version_props.object_type = 16 THEN 'Merger'ELSE CASE
WHEN version_props.object_type = 17 THEN 'Pivot'ELSE CASE
WHEN version_props.object_type = 18 THEN 'Session Obsolete'ELSE CASE
WHEN version_props.object_type = 19 THEN 'Batch'ELSE CASE
WHEN version_props.object_type = 20 THEN 'Shortcut'ELSE CASE
WHEN version_props.object_type = 21 THEN 'Mapping'ELSE CASE


WHEN version_props.object_type = 26 THEN 'Rank'ELSE CASE
WHEN version_props.object_type = 27 THEN 'Star Schema'ELSE CASE
WHEN version_props.object_type = 28 THEN 'Folder Version'ELSE CASE
WHEN version_props.object_type = 29 THEN 'Folder'ELSE CASE
WHEN version_props.object_type = 30 THEN 'Cube'ELSE CASE
WHEN version_props.object_type = 31 THEN 'Dimension'ELSE CASE
WHEN version_props.object_type = 32 THEN 'Level'ELSE CASE
WHEN version_props.object_type = 33 THEN 'Hierarchy'ELSE CASE
WHEN version_props.object_type = 34 THEN 'Fact Table'ELSE CASE
WHEN version_props.object_type = 35 THEN 'General Object'ELSE CASE
WHEN version_props.object_type = 36 THEN 'FTP Object'ELSE CASE
WHEN version_props.object_type = 37 THEN 'Oracle External Loader Object'ELSE CASE
WHEN version_props.object_type = 38 THEN 'Informix External Loader Object'
ELSE CASE
WHEN version_props.object_type = 39 THEN 'Sybase IQ External Loader Object'ELSE CASE
WHEN version_props.object_type = 54 THEN 'Sybase IQ 12 External Loader Object'ELSE CASE
WHEN version_props.object_type = 53 THEN 'Tera Data External Loader Object'ELSE CASE
WHEN version_props.object_type = 40 THEN 'File Object'ELSE CASE
WHEN version_props.object_type = 41 THEN 'Server Object'ELSE CASE
WHEN version_props.object_type = 42 THEN 'Database Object'ELSE CASE
WHEN version_props.object_type = 43 THEN 'Repository'ELSE CASE
WHEN version_props.object_type = 44 THEN 'Mapplet'ELSE CASE
WHEN version_props.object_type = 45 THEN 'Application Source Qualifier'      ELSE CASE
WHEN version_props.object_type = 46 THEN 'Input Transformation'ELSE CASE
WHEN version_props.object_type = 47 THEN 'Output Transformation'ELSE CASE
WHEN version_props.object_type = 50 THEN 'Advanced External Procedure'ELSE CASE
WHEN version_props.object_type = 48 THEN 'Business Component Framework'ELSE CASE
WHEN version_props.object_type = 49 THEN 'Business Component'ELSE CASE
WHEN version_props.object_type = 51 THEN 'SAP Structure'ELSE CASE
WHEN version_props.object_type = 52 THEN 'SAP Function'ELSE CASE
WHEN version_props.object_type = 15 THEN 'Router'ELSE CASE
WHEN version_props.object_type = 55 THEN 'XML Source Qualifier'ELSE CASE
WHEN version_props.object_type = 56 THEN 'MQ Source Qualifier'ELSE CASE
WHEN version_props.object_type = 57 THEN 'MQ Connection Object'ELSE CASE
WHEN version_props.object_type = 58 THEN 'Command'ELSE CASE
WHEN version_props.object_type = 59 THEN 'Decision'ELSE CASE
WHEN version_props.object_type = 60 THEN 'Event Wait'ELSE CASE
WHEN version_props.object_type = 61 THEN 'Event Raise'ELSE CASE
WHEN version_props.object_type = 62 THEN 'Start'ELSE CASE
WHEN version_props.object_type = 63 THEN 'Abort'ELSE CASE
WHEN version_props.object_type = 64 THEN 'Stop'ELSE CASE
WHEN version_props.object_type = 65 THEN 'Email'ELSE CASE
WHEN version_props.object_type = 66 THEN 'Timer'ELSE CASE
WHEN version_props.object_type = 67 THEN 'Assignment'ELSE CASE
WHEN version_props.object_type = 68 THEN 'Session'ELSE CASE
WHEN version_props.object_type = 69 THEN 'Scheduler'ELSE CASE
WHEN version_props.object_type = 70 THEN 'Worklet'ELSE CASE
WHEN version_props.object_type = 71 THEN 'Workflow'ELSE CASE
WHEN version_props.object_type = 72 THEN 'SessionConfig'ELSE CASE
WHEN version_props.object_type = 73 THEN 'Relational'ELSE CASE
WHEN version_props.object_type = 74 THEN 'Application'ELSE CASE
WHEN version_props.object_type = 75 THEN 'FTP'ELSE CASE
WHEN version_props.object_type = 76 THEN 'External Loader'ELSE CASE
WHEN version_props.object_type = 77 THEN 'Queue'ELSE CASE
WHEN version_props.object_type = 78 THEN 'Reader'ELSE CASE
WHEN version_props.object_type = 79 THEN 'Writer'ELSE CASE
WHEN version_props.object_type = 80 THEN 'Sorter'ELSE CASE
WHEN version_props.object_type = 81 THEN 'Vendor'ELSE CASE
WHEN version_props.object_type = 84 THEN 'App Multi-Group Source Qualifier'ELSE CASE
WHEN version_props.object_type = 91 THEN 'Control'ELSE CASE
WHEN version_props.object_type = 92 THEN 'Transaction Control'ELSE CASE
WHEN version_props.object_type = 97 THEN 'Custom Transformation'ELSE CASE
WHEN version_props.object_type = 93 THEN 'Query'ELSE CASE
WHEN version_props.object_type = 94 THEN 'Deployment Group'ELSE CASE
WHEN version_props.object_type = 95 THEN 'Label'ELSE CASE
WHEN version_props.object_type = 96 THEN 'Deployed Deployment Group'ELSE CASE
WHEN version_props.object_type = 98 THEN 'Server Grid'ELSE CASE
WHEN version_props.object_type = 99 THEN 'Profiling Ruleset'ELSE CASE
WHEN version_props.object_type = 100 THEN 'Template Extension'ELSE CASE
WHEN version_props.object_type = 101 THEN 'Global Profile Resource'ELSE CASE
WHEN version_props.object_type = 102 THEN 'Web Services Hub'ELSE CASE
WHEN version_props.object_type = 103 THEN 'Lookup Extension'ELSE CASE
WHEN version_props.object_type = 105 THEN 'Service Level'ELSE CASE
WHEN version_props.object_type = 106 THEN 'User Defined Function' ELSE 'Shortcut'

ENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDEND         ENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDEND         ENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDEND         ENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDENDEND         ENDENDENDENDENDENDENDENDENDENDENDEND


END "OBJECT_TYPE"
FROM rep_users version_users,
rep_version_props version_props,
rep_reposit_info version_reposit_info,
rep_subject version_subject
WHERE (version_props.user_id = version_users.user_id
AND version_props.object_id <> version_reposit_info.repository_id
AND version_props.subject_id = version_subject.subject_id
)
ORDER BY 3, 1
				
			

9.9 Search for a word or command used in Expression Transformation

				
					SELECT DISTINCT REP_ALL_MAPPINGS.SUBJECT_AREA, REP_ALL_MAPPINGS.MAPPING_NAME,                REP_WIDGET_INST.WIDGET_TYPE_NAME AS TRANSFORMATION_TYPE,
REP_WIDGET_INST.INSTANCE_NAME
AS TRANSFORMATION_NAME,
REP_WIDGET_FIELD.FIELD_NAME
AS PORT_NAME,
CASE
WHEN REP_WIDGET_FIELD.PORTTYPE
= 1 THEN 'I'
WHEN REP_WIDGET_FIELD.PORTTYPE
= 2 THEN 'O'
WHEN REP_WIDGET_FIELD.PORTTYPE
= 3 THEN 'IO'
WHEN REP_WIDGET_FIELD.PORTTYPE
= 32 THEN 'V'
END AS PORT_TYPE,
REP_WIDGET_FIELD.EXPRESSION
FROM REP_WIDGET_INST, REP_WIDGET_FIELD, REP_ALL_MAPPINGS
WHERE REP_WIDGET_INST.WIDGET_ID =
REP_WIDGET_FIELD.WIDGET_ID
AND REP_WIDGET_INST.MAPPING_ID =
REP_ALL_MAPPINGS.MAPPING_ID
AND REP_WIDGET_INST.WIDGET_TYPE = 5
--AND REP_WIDGET_FIELD.EXPRESSION LIKE '%CONCAT%'
ORDER BY 1
				
			

9.10 Check Input, output, Input output and Variable ports used in Expression Transformation

				
					SELECT DISTINCT REP_ALL_MAPPINGS.SUBJECT_AREA, REP_ALL_MAPPINGS.MAPPING_NAME,                REP_WIDGET_INST.WIDGET_TYPE_NAME AS TRANSFORMATION_TYPE,
REP_WIDGET_INST.INSTANCE_NAME
AS TRANSFORMATION_NAME,
REP_WIDGET_FIELD.FIELD_NAME
AS PORT_NAME,
CASE
WHEN REP_WIDGET_FIELD.PORTTYPE
= 1 THEN 'I'
WHEN REP_WIDGET_FIELD.PORTTYPE
= 2 THEN 'O'
WHEN REP_WIDGET_FIELD.PORTTYPE
= 3 THEN 'IO'
WHEN REP_WIDGET_FIELD.PORTTYPE
= 32 THEN 'V'
END AS PORT_TYPE,
REP_WIDGET_FIELD.EXPRESSION
FROM REP_WIDGET_INST, REP_WIDGET_FIELD, REP_ALL_MAPPINGS
WHERE REP_WIDGET_INST.WIDGET_ID =
REP_WIDGET_FIELD.WIDGET_ID
AND REP_WIDGET_INST.MAPPING_ID =
REP_ALL_MAPPINGS.MAPPING_ID
AND REP_WIDGET_INST.WIDGET_TYPE = 5
ORDER BY 1
				
			

9.11 List of all port details of an Expression transformations

				
					SELECT S.SUBJ_NAME, W.WIDGET_NAME, F.FIELD_ID,F.FIELD_NAME,E.VERSION_NUMBER, E.EXPRESSION
FROM OPB_WIDGET W, OPB_SUBJECT S, OPB_WIDGET_FIELD F, OPB_WIDGET_EXPR R, OPB_EXPRESSION E
WHERE W.SUBJECT_ID=S.SUBJ_ID AND W.WIDGET_ID=F.WIDGET_ID
AND W.WIDGET_ID=R.WIDGET_ID AND F.FIELD_ID=R.OUTPUT_FIELD_ID
AND W.WIDGET_ID=E.WIDGET_ID AND R.EXPR_ID=E.EXPR_ID
AND W.VERSION_NUMBER = F.VERSION_NUMBER
AND F.VERSION_NUMBER = R.VERSION_NUMBER
AND R.VERSION_NUMBER = E.VERSION_NUMBER
AND W.IS_VISIBLE = 1
AND W.WIDGET_NAME LIKE 'EXP_%'
ORDER BY 1,2,3
				
			

9.12 List of all Expression transformation port links

				
					SELECT DISTINCT S.SUBJ_NAME, WF.INSTANCE_NAME
||'.'|| F.FIELD_NAME
FROM_NAME, F.FIELD_ORDER
AS EXP_PORT_ORDER,
WT.INSTANCE_NAME ||'.'|| T.FIELD_NAME TO_NAME,  T.FIELD_ORDER
FROM OPB_WIDGET Z, OPB_WIDGET_INST WF, OPB_WIDGET_INST WT,
OPB_WIDGET_FIELD F, OPB_WIDGET_FIELD T, OPB_WIDGET_DEP D, OPB_SUBJECT S
WHERE Z.SUBJECT_ID = S.SUBJ_ID
AND Z.IS_VISIBLE = 1
AND Z.WIDGET_ID = F.WIDGET_ID
AND Z.WIDGET_ID =
WF.WIDGET_ID
AND Z.RU_VERSION_NUMBER =
WF.VERSION_NUMBER
AND WF.REF_VERSION_NUMBER = F.VERSION_NUMBER
AND WF.VERSION_NUMBER = D.VERSION_NUMBER
AND WF.MAPPING_ID = D.MAPPING_ID
AND WF.INSTANCE_ID = D.FROM_INSTANCE_ID
AND F.FIELD_ID = D.FROM_FIELD_ID
AND D.TO_INSTANCE_ID =
WT.INSTANCE_ID
AND D.TO_FIELD_ID = T.FIELD_ID
AND D.MAPPING_ID =
WT.MAPPING_ID
AND D.VERSION_NUMBER =
WT.VERSION_NUMBER
AND WT.WIDGET_ID = T.WIDGET_ID
AND WT.REF_VERSION_NUMBER = T.VERSION_NUMBER
--AND
Z.WIDGET_NAME LIKE 'EXP_%'
AND S.SUBJ_NAME = :FOLDER_NAME
AND WF.INSTANCE_NAME = :EXP_NAME
ORDER BY 1,2,3
				
			

9.13 List of LKP transformation port links used in all mappings

				
					SELECT DISTINCT OPB_SUBJECT.SUBJ_NAME,OPB_MAPPING.MAPPING_NAME,
OPB_WIDGET_FIELD.FIELD_NAME FIELD_NAME,
OPB_EXPRESSION.EXPRESSION EXPRESSION
FROM OPB_WIDGET_EXPR, OPB_EXPRESSION, OPB_WIDGET_FIELD, REP_FLD_DATATYPE, OPB_WIDGET, OPB_SUBJECT,OPB_WIDGET_INST,OPB_MAPPING
WHERE
OPB_WIDGET_FIELD.WIDGET_ID = OPB_WIDGET.WIDGET_ID
AND OPB_WIDGET.SUBJECT_ID
= OPB_SUBJECT.SUBJ_ID
AND OPB_WIDGET_INST.WIDGET_ID = OPB_WIDGET.WIDGET_ID
AND OPB_MAPPING.MAPPING_ID
= OPB_WIDGET_INST.MAPPING_ID
AND OPB_WIDGET_FIELD.VERSION_NUMBER = OPB_WIDGET.VERSION_NUMBER
AND OPB_WIDGET.IS_VISIBLE
= 1
AND OPB_WIDGET_FIELD.WIDGET_ID= OPB_WIDGET_EXPR.WIDGET_ID
AND OPB_WIDGET_FIELD.FIELD_ID= OPB_WIDGET_EXPR.OUTPUT_FIELD_ID
AND OPB_WIDGET_EXPR.WIDGET_ID=OPB_EXPRESSION.WIDGET_ID
AND OPB_WIDGET_EXPR.EXPR_ID=OPB_EXPRESSION.EXPR_ID
AND OPB_EXPRESSION.LINE_NO = 1
AND OPB_WIDGET_EXPR.VERSION_NUMBER = OPB_EXPRESSION.VERSION_NUMBER
AND OPB_WIDGET_EXPR.VERSION_NUMBER = OPB_WIDGET_FIELD.VERSION_NUMBER
--AND
OPB_SUBJECT.SUBJ_NAME = 'FOLDER_NAME'
--AND
OPB_MAPPING.MAPPING_NAME = 'MAPPING_NAME'
AND UPPER(EXPRESSION) LIKE '%LKP_ACCT_B%'
ORDER BY 1,2
				
			

9.14 List LKP Conditions of all LKP Transformations

				
					SELECT
DISTINCT
S.SUBJ_NAME,
M.MAPPING_NAME,
V.FIELD_NAME,
V.EXPRESSION,
V.MAP_UPDATE_DATE
FROM
V_LKP_FLDS_IN_COND_EXTRACT V, OPB_MAPPING M , OPB_SUBJECT S
WHERE
V.SUBJECT_ID = 23
AND
V.MAPPING_ID = M.MAPPING_ID
AND
V.SUBJECT_ID = S.SUBJ_ID
				
			

9.15 Identify ports in EXP (I, IO, O,V Ports)

				
					SELECT rep_all_mappings.subject_area, rep_all_mappings.mapping_name,
rep_widget_inst.widget_type_name AS transformation_type,
rep_widget_inst.instance_name AS transformation_name, rep_widget_field.field_name
AS port_name,
CASE WHEN rep_widget_field.porttype=1 THEN 'I'
WHEN rep_widget_field.porttype=2 THEN 'O'
WHEN rep_widget_field.porttype=3 THEN 'IO'
WHEN rep_widget_field.porttype=32 THEN 'V'
END AS port_type,
rep_widget_field.expression
FROM rep_widget_inst, rep_widget_field, rep_all_mappings
WHERE rep_widget_inst.widget_id=rep_widget_field.widget_id
AND rep_widget_inst.mapping_id=rep_all_mappings.mapping_id
AND rep_widget_inst.widget_type IN (5,9)

				
			

9.16 SQ and Lookup SQL

				
					SELECT DISTINCT
C.SUBJECT_AREA,
C.MAPPING_NAME,C.MAPPING_ID,
B.WIDGET_TYPE_NAME AS TRANSFORMATION_TYPE,
B.INSTANCE_NAME AS TRANSFORMATION_NAME,
X.SQL_SQUERY
FROM
(SELECT A.ATTR_NAME,A.ATTR_VALUE AS SQL_SQUERY,A.WIDGET_ID,A.MAPPING_ID FROM REP_WIDGET_ATTR A
WHERE WIDGET_TYPE IN (3,11) -- USE 3 FOR SOURCE QUALIFIER AND 11 FOR
LOOKUP PROCEDURE
AND A.ATTR_ID= 1
AND A.ATTR_VALUE IS NOT NULL) X,
REP_WIDGET_INST B,
REP_ALL_MAPPINGS C
WHERE
X.WIDGET_ID = B. WIDGET_ID
AND X.MAPPING_ID = C.MAPPING_ID
ORDER BY 1,2,3
				
			

9.17 B2B Transformation List

				
					WITH b2b_widgets AS

( SELECT widget_id FROM opb_widget_attr WHERE attr_value='pmudtsrv'

)
SELECT f.server_name AS server_name,

f.subject_area     AS folder_name,

f.workflow_name    AS workflow_name,

e.instance_name    AS
session_name,

c.mapping_name,

b.instance_name AS trans_name
FROM b2b_widgets a
INNER JOIN opb_widget_inst b
ON a.widget_id = b.widget_id
INNER JOIN opb_mapping c
ON b.mapping_id = c.mapping_id
INNER JOIN opb_session d
ON b.mapping_id = d.mapping_id
INNER JOIN rep_task_inst e
ON d.session_id = e.task_id
INNER JOIN rep_workflows f
ON e.workflow_id = f.workflow_id;
				
			

9.18 List all Update Transformations

				
					

SELECT
DISTINCT SUBJECT_AREA AS FOLDER_NAME,
  B.WIDGET_TYPE_NAME,
  (PARENT_MAPPING_NAME) AS MAPPING_NAME
FROM
REP_ALL_MAPPINGS A,
  REP_WIDGET_INST B
WHERE
A.PARENT_MAPPING_ID = B.MAPPING_ID
AND
A.PARENT_SUBJECT_ID   = B.SUBJECT_ID
AND
B.WIDGET_TYPE_NAME    = 'Update Strategy'
				
			
Aggregator
App Multi-Group Source Qualifier
Application Source Qualifier
Custom Transformation
Expression
Filter
Input Transformation
Joiner
Lookup Procedure
Mapplet
Normalizer
Output Transformation
Rank
Router
Sequence
Sorter
Source Definition
Source Qualifier
Stored Procedure
Target Definition
Transaction Control
Update Strategy
XML Source Qualifier

9.19 List Sequence Transformation Details

				
					SELECT
SEQNAME AS SEQUENCE_NAME,
SEQVAL AS SEQUENCE_VALUE,
SEQINCR AS SEQUENCE_INC_VALUE
FROM OPB_RTSEQ
				
			

9.20 Expression Identifier

Below query identifies the list of mappings which uses particular column logic in the Expression transformations (Query can also be customized with filter to fetch the Expressions logics used in a particular mapping).

				
					SELECT /*+ Index map.MAPPING_NAME idx1 */

DISTINCT sub.subj_name, MAP.mapping_name, owi.instance_name,

owf.field_name, oe.expression

FROM opb_subject sub,

(SELECT mapping_id, mapping_name, subject_id, version_number,

is_valid, is_visible, ref_widget_id

FROM opb_mapping

WHERE is_visible = 1 AND ref_widget_id = 0) MAP,

opb_widget_inst owi,

opb_expression oe,

opb_widget_expr owe,

opb_widget_field owf

WHERE sub.subj_id = MAP.subject_id

AND MAP.mapping_id = owi.mapping_id

AND owi.widget_type = 5

AND MAP.version_number = owi.version_number

AND owi.widget_id = oe.widget_id

AND owi.ref_version_number = oe.version_number

AND owi.widget_id = owe.widget_id

AND owi.ref_version_number = owe.version_number

AND owi.widget_id = owf.widget_id

AND owi.ref_version_number = owf.version_number

AND owe.expr_id = oe.expr_id

AND owe.output_field_id = owf.field_id

/* Input your mapping_name ,which is optional */

-- ANd map.mapping_name='m_LOAD_SAMPLE_MAPPING'

/* Input your Expression Here */

AND oe.expression LIKE ('%IIF%')

ORDER BY sub.subj_name, MAP.mapping_name
				
			

9.21 LOOKUP_OVERRIDE_SQL

Below query identifies the SQL override for a particular mapping in Informatica repository (Query can also be customized with filter to fetch the mappings which use a particular table in its Look up SQL override).

				
					SELECT DISTINCT sub.subj_name AS folder_name, mapp.mapping_name,

owi.instance_name AS lookup_name,

OWA.attr_value AS lookup_sql_override_query

FROM opb_subject sub,

(SELECT subject_id, mapping_name, mapping_id

FROM opb_mapping

WHERE is_visible = 1 AND ref_widget_id = 0) mapp,

(SELECT a.mapping_id, a.widget_id, a.widget_type, a.instance_id,

a.instance_name

FROM opb_widget_inst a

WHERE a.widget_type = 11

AND a.version_number = (SELECT MAX (version_number)

FROM opb_widget_inst b

WHERE a.mapping_id = b.mapping_id)) owi,

(SELECT a.widget_id, a.widget_type, a.attr_id, a.attr_value

FROM opb_widget_attr a

WHERE a.version_number = (SELECT MAX (b.version_number)

FROM opb_widget_attr b

WHERE a.widget_id = b.widget_id)) OWA

WHERE sub.subj_id = mapp.subject_id

AND mapp.mapping_id = owi.mapping_id

AND owi.widget_id = OWA.widget_id

AND owi.widget_type = OWA.widget_type

AND OWA.attr_id = 1

/* Mapping_name, which is optional */

AND mapp.mapping_name LIKE 'm_LOAD_SAMPLE_MAPPING'

/* Input LOOKUP_TABLE_NAME */

-- AND OWA.attr_value LIKE ('%LOOKUP_TABLE_NAME%')

 
				
			

9.22 Folder Level Reusable Transformations

Below query gives active reusable transformations list for a particular folder in Informatica repository.

				
					SELECT sub.subj_name AS subject_name, ow.widget_name AS trasnformation_name

FROM opb_subject sub, opb_widget ow

WHERE sub.subj_id = ow.subject_id

AND ow.is_reusable = 1

AND ow.is_visible = 1

/* Input your subject Name*/

AND sub.subj_name = 'FolderName'

UNION ALL

SELECT sub.subj_name AS subject_name, os.shortcut_name

FROM opb_subject sub, opb_shortcut os

WHERE sub.subj_id = os.subject_id

AND os.is_visible = 1

AND os.object_type = 23

/* Input your subject Name */

AND sub.subj_name = 'FolderName'
				
			

9.23 Router Conditions

				
					SELECT b.subj_name, a.mapping_name, c.instance_name, d.group_name, d.attr_value

FROM opb_mapping a,

opb_subject b,

opb_widget_inst c,

(SELECT o.object_type, o.object_id, o.attr_value AS group_name, o1.attr_value, o.version_number

FROM opb_table_group o, opb_table_group o1

WHERE o.object_id = o1.object_id

AND o.attr_id = 1

AND o1.attr_id = 3

AND o.GROUP_ID = o1.GROUP_ID

AND o.version_number = o1.version_number) d

WHERE a.subject_id = b.subj_id

AND a.mapping_id = c.mapping_id

AND a.is_visible = 1

AND a.version_number = c.version_number

AND c.widget_type = d.object_type

AND c.widget_id = d.object_id

AND c.ref_version_number = d.version_number

AND a.mapping_name = 'm_LOAD_DIFP_OL'
				
			

9.24 Uncommented Transformations

Below query identifies the transformations list for which comments were not entered.

				
					SELECT s.subj_name AS folder, m.mapping_name AS MAPPING,

owi.instance_name AS transformation,

owi.comments AS transformation_comments

FROM opb_subject s, opb_mapping m, opb_widget ow, opb_widget_inst owi

WHERE s.subj_id = m.subject_id

AND m.is_visible = 1

AND m.ref_widget_id = 0

AND m.mapping_id = owi.mapping_id

AND m.version_number = owi.version_number

AND owi.widget_id = ow.widget_id

AND owi.comments IS NULL

AND ow.is_visible = 1

AND ow.is_reusable <> 1

AND owi.widget_type NOT IN (1, 2, 46, 47)

-- Input mapping name

AND m.mapping_name = 'm_LOAD_DIFPRS_P_CCTR_PROTOCOL_STUDY_RPT'

-- Input subject name, whcih is optional

-- AND s.subj_name = UPPER ('DIF_STG_POPULATION')

ORDER BY 1, 2, 3