@@ -2090,3 +2090,161 @@ BEGIN
2090
2090
END;$$;
2091
2091
2092
2092
COMMENT ON FUNCTION oracle_migrate(name, name, name, name[], integer) IS ' migrate an Oracle database from a foreign server to PostgreSQL' ;
2093
+
2094
+ CREATE FUNCTION quote_xml (text ) RETURNS text
2095
+ LANGUAGE sql IMMUTABLE STRICT AS
2096
+ $$SELECT replace(
2097
+ replace(
2098
+ replace(
2099
+ replace(
2100
+ replace(
2101
+ $1 ,
2102
+ ' ' ' ' , ' ''
2103
+ ),
2104
+ ' &' , ' &'
2105
+ ),
2106
+ ' "' , ' "'
2107
+ ),
2108
+ ' >' , ' >'
2109
+ ),
2110
+ ' <' , ' <'
2111
+ )$$;
2112
+
2113
+ CREATE FUNCTION oracle_export (
2114
+ application_name text DEFAULT TEXT ' application' ,
2115
+ pgstage_schema name DEFAULT NAME ' pgsql_stage' ,
2116
+ only_schemas name[] DEFAULT NULL
2117
+ ) RETURNS xml
2118
+ LANGUAGE plpgsql VOLATILE STRICT SET search_path = pg_catalog AS
2119
+ $$DECLARE
2120
+ result text := E' <?xml version="1.0" encoding="UTF-8"?>\n '
2121
+ ' <?xml-stylesheet type="text/xsl" href="xenesis.xsl"?>\n ' ;
2122
+ extschema name;
2123
+ s name;
2124
+ t name;
2125
+ c name;
2126
+ ty name;
2127
+ nul boolean ;
2128
+ con name;
2129
+ old_con name;
2130
+ rs name;
2131
+ rt name;
2132
+ rc name;
2133
+ BEGIN
2134
+ /* set "search_path" to the PostgreSQL staging schema and the extension schema */
2135
+ SELECT extnamespace::regnamespace INTO extschema
2136
+ FROM pg_catalog .pg_extension
2137
+ WHERE extname = ' ora_migrator' ;
2138
+ EXECUTE format(' SET LOCAL search_path = %I, %I' , pgstage_schema, extschema);
2139
+
2140
+ /* translate schema names to lower case */
2141
+ only_schemas := array_agg(oracle_tolower(os)) FROM unnest(only_schemas) os;
2142
+
2143
+ result := result || E' <application name="' || quote_xml(application_name)
2144
+ || E' " xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xsi:schemaLocation="xenesis.xsd">\n ' ;
2145
+
2146
+ /* loop schemas */
2147
+ FOR s IN
2148
+ SELECT schema FROM schemas
2149
+ WHERE (only_schemas IS NULL
2150
+ OR schema = ANY (only_schemas))
2151
+ LOOP
2152
+ result := result || E' <module name="' || quote_xml(s) || E' ">\n ' ;
2153
+
2154
+ /* loop all migrated tables in schema */
2155
+ FOR t IN
2156
+ SELECT table_name FROM tables
2157
+ WHERE migrate AND schema = s
2158
+ AND (only_schemas IS NULL
2159
+ OR schema = ANY (only_schemas))
2160
+ LOOP
2161
+ result := result || E' \n <entity name="' || quote_xml(t) || E' ">\n '
2162
+ ' <attributes>\n ' ;
2163
+
2164
+ /* loop all columns in the table */
2165
+ FOR c, ty, nul IN
2166
+ SELECT column_name, type_name, nullable
2167
+ FROM columns
2168
+ WHERE schema = s AND table_name = t
2169
+ AND (only_schemas IS NULL
2170
+ OR schema = ANY (only_schemas))
2171
+ ORDER BY position
2172
+ LOOP
2173
+ result := result || E' <attribute name="' || quote_xml(c)
2174
+ || E' " datatype="' || quote_xml(ty)
2175
+ || E' " required="' || CASE WHEN nul THEN ' false' ELSE ' true' END
2176
+ || E' "/>\n ' ;
2177
+ END LOOP;
2178
+
2179
+ result := result || E' </attributes>\n\n '
2180
+ ' <restrictions>\n ' ;
2181
+
2182
+ /* loop through all unique and primary key contraints for the table */
2183
+ old_con := ' ' ;
2184
+ FOR con, c IN
2185
+ SELECT constraint_name, column_name
2186
+ FROM keys
2187
+ WHERE schema = s AND table_name = t
2188
+ AND (only_schemas IS NULL
2189
+ OR schema = ANY (only_schemas))
2190
+ ORDER BY position
2191
+ LOOP
2192
+ IF con <> old_con THEN
2193
+ IF old_con <> ' ' THEN
2194
+ result := result || E' </unique>\n ' ;
2195
+ END IF;
2196
+
2197
+ result := result || E' <unique>\n ' ;
2198
+ old_con := con;
2199
+ END IF;
2200
+
2201
+ result := result || E' <unique-attribute name="'
2202
+ || quote_xml(c) || E' "/>\n ' ;
2203
+ END LOOP;
2204
+ IF old_con <> ' ' THEN
2205
+ result := result || E' </unique>\n ' ;
2206
+ END IF;
2207
+
2208
+ /* loop through all foreign key constraints on the table */
2209
+ old_con := ' ' ;
2210
+ FOR con, c, rs, rt, rc IN
2211
+ SELECT constraint_name, column_name, remote_schema, remote_table, remote_column
2212
+ FROM foreign_keys
2213
+ WHERE schema = s AND table_name = t
2214
+ AND (only_schemas IS NULL
2215
+ OR schema = ANY (only_schemas)
2216
+ AND remote_schema = ANY (only_schemas))
2217
+ ORDER BY position
2218
+ LOOP
2219
+ IF con <> old_con THEN
2220
+ IF old_con <> ' ' THEN
2221
+ result := result || E' </reference>\n ' ;
2222
+ END IF;
2223
+
2224
+ result := result || E' <reference target-module="'
2225
+ || quote_xml(rs) || E' " target-entity="'
2226
+ || quote_xml(rt) || E' ">\n ' ;
2227
+ old_con := con;
2228
+ END IF;
2229
+
2230
+ result := result || E' <reference-attribute name="'
2231
+ || quote_xml(c) || E' " target-attribute="'
2232
+ || quote_xml(rc) || E' "/>\n ' ;
2233
+ END LOOP;
2234
+ IF old_con <> ' ' THEN
2235
+ result := result || E' </reference>\n ' ;
2236
+ END IF;
2237
+
2238
+ result := result || E' </restrictions>\n '
2239
+ ' </entity>\n ' ;
2240
+ END LOOP;
2241
+
2242
+ result := result || E' </module>\n\n ' ;
2243
+ END LOOP;
2244
+
2245
+ result := result || E' </application>' ;
2246
+
2247
+ RETURN result::xml;
2248
+ END$$;
2249
+
2250
+ COMMENT ON FUNCTION oracle_export(text, name, name[]) IS ' export metadata to an XML file' ;
0 commit comments