├── .gitignore ├── CHANGELOG ├── LICENSE ├── Makefile ├── README.md ├── README.oracle_fdw ├── TODO ├── expected ├── oracle_fdw.out ├── oracle_gis.out ├── oracle_import.out └── oracle_join.out ├── msvc ├── oracle_fdw.props ├── oracle_fdw.sln ├── oracle_fdw.vcxproj └── oracle_msvc.c ├── oracle_fdw--1.0--1.1.sql ├── oracle_fdw--1.1--1.2.sql ├── oracle_fdw--1.2.sql ├── oracle_fdw.c ├── oracle_fdw.control ├── oracle_fdw.h ├── oracle_gis.c ├── oracle_utils.c └── sql ├── oracle_fdw.sql ├── oracle_gis.sql ├── oracle_import.sql └── oracle_join.sql /.gitignore: -------------------------------------------------------------------------------- 1 | # Object files 2 | *.o 3 | *.obj 4 | 5 | # Libraries 6 | *.lib 7 | *.a 8 | 9 | # Shared objects (inc. Windows DLLs) 10 | *.dll 11 | *.so 12 | *.so.* 13 | *.dylib 14 | *.bc 15 | 16 | # Executables 17 | *.exe 18 | 19 | # Regression test results 20 | results 21 | regression.out 22 | regression.diffs 23 | 24 | # dependency tracking 25 | .deps 26 | 27 | # other version control systems 28 | CVS 29 | .svn 30 | 31 | # Windows build, build output 32 | v15 33 | msvc/*.opensdf 34 | msvc/*.sdf 35 | msvc/*.suo 36 | msvc/*.vcxproj.filters 37 | msvc/Win32 38 | msvc/x64 39 | -------------------------------------------------------------------------------- /CHANGELOG: -------------------------------------------------------------------------------- 1 | Version 2.8.0, released 2025-05-10 2 | 3 | Bugfixes: 4 | - Throw an error if "ctid" or other system columns are used in the WHERE 5 | clause. Since these columns have no meaning in Oracle, they are assigned 6 | meaningless values, and using them in WHERE conditions would lead to 7 | meaningless results. 8 | Reported in https://stackoverflow.com/q/78823195/6464308 9 | - Fix the server option "nchar" introduced in 2.4.0. 10 | Due to an omission, that option never worked, and NCHAR and NVARCHAR2 11 | columns were converted wrongly even if "nchar" was "on". 12 | Report and analysis by Andrey Teplitskiy. 13 | - Fix IMPORT FOREIGN SCHEMA so that it imports tables whose name is the same 14 | as the name of an index. 15 | Report by Leho Lehes. 16 | - Don't push down LIMIT. 17 | This is a regression from older releases, but the current implementation 18 | was incorrect, as reported by "gytune74". 19 | - Fix a crash with column options on non-existing columns. 20 | If the Oracle table has fewer columns than the PostgreSQL foreign table and 21 | one of these extra columns has a column option set, oracle_fdw would 22 | crashes. 23 | Reported by "ganshinm", analysis by "ziva777". 24 | - Increase the size of the Oracle execution plan lines. 25 | With the previous limit of 1000, EXPLAIN (VERBOSE) for some Oracle metadata 26 | queries resulted in 27 | ORA-01406: fetched column value was truncated 28 | Report by "ganshinm" and Egor Chindyaskin. 29 | 30 | Enhancements: 31 | - Raise the limit for "prefetch" to 10240 again, like it was before 32 | version 2.6.0. Requested by Martin Nash, "AmebaBrain" and others. 33 | Note that high values increase the risk of out-of-memory errors. 34 | - Add support for NCLOB. 35 | Patch by Marti Raudsepp. 36 | 37 | Version 2.7.0, released 2024-08-01 38 | 39 | Bugfixes: 40 | - Don't push down LIMIT without an ORDER BY clause. 41 | This can lead to wrong results in some cases. 42 | Report by "fbattke". 43 | - Fix support for query parameters of type "uuid". 44 | This led to errors like 45 | error executing query: OCINumberFromText failed to convert parameter 46 | OCI-22062: invalid input string [8feee298-7ce5-4761-9487-34cab831fead] 47 | Report by "victorras". 48 | - Fix a memory leak in statements that return LOBs. 49 | The memory for LOB locators didn't get released before the end of the 50 | transaction, so running many statements in a single transaction could cause 51 | out-of-memory errors and server crashes. 52 | Report by "JosefMachytkaNetApp". 53 | - Fix building on Windows with PostgreSQL versions older than v15. 54 | This used to report "unresolved external symbol XactReadOnly". 55 | Report by "w0pr". 56 | - Fix crash or empty result when reading larger CLOBs. 57 | Report by Rainer Hartwig and Erik van der Vlist. 58 | - Bind empty string parameters as NULL values. 59 | Failure to do that led to the error 60 | ORA-01459: invalid length for variable character string 61 | during the attempt to INSERT empty strings in a foreign table. 62 | Report by Adrian Boangiu. 63 | 64 | Enhancements: 65 | - Speed up IMPORT FOREIGN SCHEMA ... LIMIT TO (...) by filtering out tables 66 | whose name don't match on the Oracle side. 67 | Per suggestion from João Filipe Cavichiolo Storrer. 68 | - Add options "skip_tables", "skip_views" and "skip_matviews" to 69 | IMPORT FOREIGN SCHEMA. 70 | From a patch by Михаил. 71 | 72 | Version 2.6.0, released 2023-09-08 73 | 74 | Note: This release will fail to build with minor releases below 13.10, 75 | 14.7 and 15.2. Other major versions are not affected. oracle_fdw 76 | binaries built with later minor releases won't load with older 77 | PostgreSQL binaries, complaining about undefined symbols. 78 | Keep the PostgreSQL server updated! 79 | 80 | Bugfixes: 81 | - Inserting CLOBs with the server option "nchar" on can lead to the error 82 | "ORA-24806: LOB form mismatch". 83 | Report and patch by "jopoly". 84 | - Don't push down LIMIT with FOR SHARE or FOR UPDATE. That caused the error 85 | ORA-02014: cannot select FOR UPDATE from view with DISTINCT, GROUP BY, etc. 86 | Reported by Marti Raudsepp. 87 | - Fix BEFORE UPDATE triggers. 88 | If a BEFORE UPDATE trigger modified a column that was not updated, the 89 | changed column was not propagated to Oracle. 90 | Report and diagnosis by "jopoly". 91 | - Don't free() strings in the environment. 92 | This could lead to crashes and unpredictable behavior. 93 | - Conversions from TIMESTAMP WITH LOCAL TIME ZONE to "timestamp without time 94 | zone" were incorrect. To fix, set the Oracle session time zone from the 95 | PostgreSQL parameter "timezone". Since not all time zones are accepted by 96 | all Oracle servers, this must be explicitly enabled by setting the 97 | "set_timezone" option on the foreign server. 98 | Thanks to Sébastien Caunes for help with this. 99 | - Make auto_explain work with oracle_fdw. This used to cause an error: 100 | oracleQueryPlan internal error: statement handle is not NULL 101 | Report by "Jaisus" and Sébastien Caunes. Sébastien provided the essential 102 | clue that the problem is related to auto_explain. 103 | - Fix "OCI-22061: invalid format text" errors when inserting some numbers 104 | with scientific notation into a foreign table. 105 | Report and analysis by "liubeck". 106 | - Support whole-row references in RETURNING clauses. 107 | Report and patch by Nguyen Ngoc Son. 108 | - Make generated columns work correctly. 109 | This will fail to build with minor releases below 13.10, 14.7 and 15.2! 110 | Report and original patch by Nguyen Ngoc Son. 111 | 112 | Enhancements: 113 | - Skip Oracle savepoint management if the foreign server option 114 | "isolation_level" is set to "read_only" or if we are inside a read-only 115 | PostgreSQL transaction. This saves some round trips and avoids Oracle 116 | errors that might be thrown when entering a PL/pgSQL exception handler. 117 | Per suggestion from "math-g". 118 | - Use explicit bulk fetching into arrays rather than OCI prefetching for 119 | Oracle SELECT statements. This greatly improves performance for LOB 120 | and LONG columns, since OCI prefetching didn't work if these data types. 121 | The limitation still applies for SDO_GEOMETRY columns. A new option 122 | "lob_prefetch" is used to configure how much of the LOBs is fetched 123 | with the rows to reduce the number of round trips. This enhancement 124 | was generously sponsored by Mipih (https://www.mipih.fr/). 125 | Thanks for Philippe Florent for help and testing! 126 | 127 | Version 2.5.0, released 2022-10-28 128 | 129 | Bugfixes: 130 | - Use the correct user mapping for views on foreign tables. 131 | This should use the mapping associated with the view owner. 132 | Reported by "JSilex". 133 | - Fix a spurious error on UPDATE or DELETE if the column options "key" and 134 | "strip_zeros" are used on the same column. 135 | Report and patch by Noriyoshi Shinoda. 136 | - Fix "out of memory" and other errors on Linux systems with FIPS enabled. 137 | The cause is that calculating MD5 hashes on such systems causes errors. 138 | Reported by Hank Drews. 139 | - Handle Oracle's TIMESTAMP WITH LOCAL TIME ZONE correctly. 140 | Oracle converts such values to its session time zone on output, but does not 141 | add a time zone offset, so PostgreSQL interpreted them incorrectly. 142 | Reported by "JamesInform". 143 | 144 | Enhancements: 145 | - Improve the Makefile so that the build process automatically detects 146 | Oracle Instant Client installations installed by packages on Linux. 147 | Patch by Christian Ullrich. 148 | 149 | Version 2.4.0, released 2021-09-24 150 | 151 | Enhancements: 152 | - Support push-down of "uuid" values. 153 | Per request from Asish Kumar Gaddipati. 154 | - Introduce a server option "nchar", turned "off" by default. 155 | This option, if set, enables the fix for NCHAR and NVARCHAR2 columns 156 | introduced in 2.3.0. 157 | We don't want that by default, since it causes a noticable performance 158 | hit and makes UPDATEs with long strings fail with ORA-01461. 159 | Problem reports by "threenotrump", "CHunter" and Philippe Florent. 160 | - Push down LIMIT clauses if possible. 161 | These are pushed down as FETCH FIRST n ROWS ONLY from Oracle 12.2 on. 162 | Based on a patch by Gilles Darold, per request from Ilia Sazonov. 163 | 164 | Bugfixes: 165 | - Fix a performance regression introduced in 2.3.0 by the fix for NCHAR 166 | and NVARCHAR2 columns. 167 | Reported by Philippe Florent. 168 | - Fix a crash with type coerced array parameters. 169 | This can make queries fail with a WHERE condition like 170 | WHERE varcharcol = ANY ($1); 171 | where $1 is a text[]. 172 | Reported by "samuelchoi16". 173 | - Fix numeric precision in IMPORT FOREIGN SCHEMA. 174 | In Oracle the precision of a NUMBER can be less than the scale, 175 | but that is not allowed in PostgreSQL. 176 | That leads to errors during IMPORT. 177 | Reported by Alberto Dell'Era. 178 | - Translate Oracle NUMBER to "boolean" correctly. 179 | The documentation says that numbers greater than 0 are mapped to 180 | TRUE, but oracle_fdw gagged on numbers greater than 1 with errors like 181 | ERROR: invalid input syntax for type boolean: "2" 182 | Reported by Maris Zinbergs. 183 | - Fix crash during ANALYZE of certain foreign tables. 184 | If the Oracle table has more columns than the foreign table, 185 | ANALYZE on the foreign table caused a crash. 186 | Reported by Jan. 187 | - Fix build with unset ORACLE_HOME and Instant Client 21. 188 | Reported by "fjf2002". 189 | - Use the correct user mapping in SECURITY DEFINER contexts. 190 | Before this, oracle_fdw always used the current user to 191 | determine the security context, which is wrong if a 192 | foreign table was accessed in a SECURITY DEFINER function. 193 | Reported by "ksmalara". 194 | 195 | Version 2.3.0, released 2020-09-24 196 | Note: When upgrading from an older version of oracle_fdw, make sure to run 197 | ALTER EXTENSION oracle_fdw UPDATE; 198 | after installing the extension. 199 | 200 | Enhancements: 201 | - Support PostgreSQL v13. Support for 9.2 and 9.1 is dropped. 202 | - Add a function "oracle_execute" to execute arbitrary SQL statements on 203 | Oracle. The statements must not return a result (e.g. DDL statements). 204 | - Add an option "dblink" for Oracle database links. 205 | The option can be used on foreign tables or with IMPORT FOREIGN SCHEMA. 206 | Patch by Nicolas Boullis. 207 | - Add a column option "strip_zeros" that automatically strips ASCII 0 208 | characters from strings. 209 | Per request from Alexander Lampalzer. 210 | - New IMPORT FOREIGN SCHEMA options "max_long", "sample_percent" and 211 | "prefetch". These set the corresponding options on imported tables. 212 | Suggested by "ferfebles". 213 | - Add support for isolation levels other than SERIALIZABLE. 214 | This is mostly because Oracle's implementation of SERIALIZABLE is so buggy. 215 | Patch by Jet C.X. Zhang. 216 | 217 | Bugfixes: 218 | - Fix bad results with uncorrelated subqueries. 219 | This affects queries have a foreign scan with a filter based on a subplan. 220 | Reported by "srakazmus". 221 | - Fix "Internal oracle_fdw error: encountered unknown node type 144" 222 | This can happen in plans involving tables with identity columns. 223 | Reported by Yang Lin. 224 | - Don't throw an error if DML statements modify no rows. 225 | This might be caused by a trigger on the Oracle side. 226 | Reported by Andrey Marinchuk. 227 | - Fix NCHAR and NVARCHAR2 handling. 228 | With single-byte Oracle character sets, this bug led to replacement 229 | characters being used for characters not in the database character set. 230 | Reported by "srakazmus", and Christian Ullrich helped with the fix. 231 | - Report a proper error for INSERT ... ON CONFLICT on partitioned tables. 232 | Report and fix by Ian Barwick. 233 | - Fix INSERT ... RETURNING if a table partition is a foreign table. 234 | It used to return NULL values by mistake. 235 | Report and analysis by Ian Barwick. 236 | 237 | Version 2.2.0, released 2019-10-10 238 | Enhancements: 239 | - Add support for COPY to foreign tables (from PostgreSQL v11 on). 240 | This caused a crash before, as reported by "jkldv". 241 | - Add a new "collation" option for IMPORT FOREIGN SCHEMA that controls 242 | case folding. 243 | Patch by Sahap Asci. 244 | - Add support for Oracle XMLTYPE. 245 | - Set V$SESSION_CONNECT_INFO.CLIENT_DRIVER to "oracle_fdw". 246 | This makes it easier to identify the session on the Oracle side. 247 | 248 | Bugfixes: 249 | - Fix crash or bad results with pushed down join queries. 250 | The query target list can change during query planning, but oracle_fdw 251 | relied on the one from before. 252 | This bug only manifests in PostgreSQL v11. 253 | Bug found by Jaime Casanova and fixed by Tatsuro Yamada. 254 | - Fix push-down of foreign scan conditions with variables belonging 255 | to other tables. 256 | This can lead to wrong results and warnings like: 257 | WARNING: column number x of foreign table "y" does not exist in 258 | foreign Oracle table, will be replaced by NULL 259 | - Fix crash in UPDATE or DELETE where the optimizer can deduce that no 260 | scan is required, for example with "WHERE 1 = 0". 261 | Reported by Andy Shipman. 262 | - Fix crash or bad results in queries with IN or "= ANY" where the element 263 | type on the right-hand side is different from the left-hand side type. 264 | - Add support for reading infinite NUMBERs. 265 | Oracle NUMBER has infinite values, which are represented as "~" and "-~". 266 | Since PostgreSQL's "numeric" does not know infinity, map these values 267 | to NaN in this case. For "real" and "double precision" we can use the 268 | normal infinity values. 269 | - The "readonly" option of IMPORT FOREIGN SCHEMA didn't work properly: 270 | When set to "false", it would still create read-only foreign tables. 271 | Reported by Jacob Roberts. 272 | 273 | Version 2.1.0, released 2018-10-01 274 | Enhancements: 275 | - Add support for the "json" PostgreSQL data type. 276 | On the Oracle side, CLOB or VARCHAR2 can be used. 277 | Suggested by "bsislow". 278 | - Add support and documentation for building with Microsoft Visual Studio. 279 | Patch by Christian Ullrich. 280 | - Enable delayed loading of the Oracle DLL on Windows. 281 | This allows better diagnostic messages if the library cannot be loaded. 282 | Patch by Christian Ullrich. 283 | - Report the correct SQLSTATE for constraint violation and deadlock errors. 284 | Idea by "omistler". 285 | - Push down outer joins to Oracle. 286 | Patch by Tatsuro Yamada, courtesy of NTT OSS Center. 287 | 288 | Bugfixes: 289 | - Missing check if Oracle data types can be converted to PostgreSQL types. 290 | This bug was introduced in 2.0.0. 291 | - When oracle_fdw is loaded, initializing background workers 292 | (e.g. for parallel query) failed with: 293 | ERROR: invalid cache ID: 41 294 | - Don't try to push down IS [NOT] DISTINCT FROM expressions. 295 | Oracle does not support this standard SQL syntax. 296 | - Don't push down IS [NOT] NULL tests on boolean expressions. 297 | This caused "ORA-00907: missing right parenthesis". 298 | Noticed by Tatsuro Yamada during testing with "sqlsmith". 299 | - Allow foreign tables to be defined on Oracle queries that contain double 300 | quotes. This caused an error message due to a sanity check that has become 301 | obsolete when this feature was introduced. 302 | Noted by "Bpapman". 303 | - Disable push-down of foreign joins in queries with FOR UPDATE. 304 | These used to be pushed down before, but without the FOR UPDATE clause, 305 | leading to incorrect behavior in the face of concurrency. 306 | Noted and fixed by Tatsuro Yamada. 307 | 308 | Version 2.0.0, released 2017-09-15 309 | Incompatible changes: 310 | - Remove the deprecated option "plan_costs", since it is not very useful and 311 | is a maintenance burden. After an upgrade, tables with this option set 312 | should be updated with: 313 | ALTER FOREIGN TABLE ... OPTIONS (DROP plan_costs); 314 | 315 | Enhancements: 316 | - Push down 2-way inner joins in SELECT statements if all conditions 317 | can be pushed down. 318 | Patch by Tatsuro Yamada, courtesy of NTT OSS Center. 319 | 320 | Bugfixes: 321 | - oracle_fdw crashed on Windows if queries use a NULL parameter or 322 | an empty subselect. 323 | Report by PAscal Lemoy. 324 | - Reading "srid.map" sometimes caused errors even if everything was alright. 325 | Report by Paul Dziemiela, analysis by Christian Ullrich. 326 | - Don't push down expressions with CLOB column references. 327 | Because of Oracle's inability to use CLOB in SQL expressions, 328 | this could lead to errors like 329 | ORA-00932: inconsistent datatypes: expected - got CLOB 330 | - Fix bug in "pg_terminate_backend" handling. 331 | "pg_terminate_backend" (or SIGTERM) was not handled 332 | correctly, since neither the Oracle query was canceled nor did 333 | the backend terminate. 334 | Reported by Dmitry Chirkin. 335 | 336 | Version 1.5.0, released 2016-08-05 337 | Enhancements: 338 | - Add table option "sample_percent" to ANALYZE very large tables 339 | This can speed up ANALYZE significantly. 340 | Idea by PAscal Lemoy. 341 | - Introduce a table option "prefetch" for the Oracle row prefetch count 342 | This can speed up foreign table scans. 343 | Per discussion with by PAscal Lemoy and Maurizio De Giorgi. 344 | - Push down arbitrary IN and NOT IN expressions 345 | Up to now, only lists with constants were considered. 346 | Per request from Volkmar Bühringer. 347 | - Push down ORDER BY expressions to Oracle from PostgreSQL 9.2 on 348 | Only expressions of numeric, date and timestamp datatypes are pushed 349 | down, since the string collations in PostgreSQL and Oracle cannot be 350 | guaranteed to be the same. 351 | Courtesy of NTT OSS Center, patch by Tatsuro Yamada. 352 | 353 | Bugfixes: 354 | - Fix errors with now() and date/timestamp parameters in queries 355 | This bug was introduced in 1.3.0 and caused errors like 356 | ERROR: error executing query: OCIDateTimeFromText failed to convert parameter 357 | DETAIL: ORA-01843: not a valid month 358 | when now() or "current_timestamp" and friends or date/timestamp 359 | parameters were used. 360 | Report by Li Hailong. 361 | - Fix errors when updating date/timestamp columns 362 | This bug was also introduced in 1.3.0 and caused errors like 363 | ORA-01856: BC/B.C. or AD/A.D. required 364 | if the Oracle and PostgreSQL types were different. 365 | Report by Stephane Tachoires. 366 | - IMPORT FOREIGN SCHEMA sometimes didn't import primary keys 367 | Report by Jean-Marc Lessard, fix by PAscal Lemoy. 368 | - Fix memory leaks during ANALYZE 369 | This caused out of memory errors when large tables were analyzed. 370 | Report by Alessio Checcucci. 371 | - IMPORT FOREIGN SCHEMA should not tolerate missing remote schema 372 | It used to cause a warning, but the SQL standard requires an error. 373 | Report by Jean-Marc Lessard. 374 | - Fix crash when UPDATEing non-existent columns 375 | If a foreign table has more columns than the underlying Oracle table, 376 | these additional columns are treated as containing NULLs. 377 | However, oracle_fdw crashed on an attempt to change such a column with 378 | an UPDATE statement, which should not happen. 379 | Reported by Fabien Nicollet. 380 | - Fetch all columns from Oracle when the whole row is referenced 381 | This problem could lead to wrong NULL values in trigger functions or when 382 | the whole column is used in an expression. 383 | Reported by Fabien Nicollet. 384 | 385 | Version 1.4.0, released 2016-04-08 386 | Enhancements: 387 | - Add option "readonly" for IMPORT FOREIGN TABLE that sets the foreign table 388 | option "readonly" to "true" on all imported foreign tables. 389 | Idea by Julien Goux. 390 | - Allow foreign tables based on arbitrary Oracle queries. 391 | The query, enclosed in parentheses, can be supplied as option "table". 392 | Requested by "tsykes", "cirix81" and Julien Goux. 393 | 394 | Bugfixes: 395 | - Selecting timestamps with lc_messages other than English caused errors like 396 | "ORA-01406: la valeur de la colonne extraite a été tronquée" 397 | Report by Damien Szczyt. 398 | - Complicated queries could lead to an error like 399 | "Internal oracle_fdw error: encountered unknown node type 524." 400 | Report by "bartonjd". 401 | - PostGIS type "geometry" cannot be found if ArcGIS is installed. 402 | Report by "dtoller". 403 | 404 | Version 1.3.0, released 2015-12-21 405 | Enhancements: 406 | - Add support for IMPORT FOREIGN SCHEMA for PostgreSQL 9.5 and higher. 407 | - Improve cost estimates by using the row count estimate. 408 | Inspiration by Daniele Sevegnani. 409 | - Support two-dimensional geometries with an additional measure dimension. 410 | Idea by Paul Dziemiela. 411 | - Throw an error if oracle_close_connections() is called inside a 412 | transaction that modified Oracle data. 413 | 414 | Bugfixes: 415 | - The server crashed for the constructs like " = ANY (NULL)". 416 | Report and patch by dreckard. 417 | - oracle_fdw sometimes failed to recognize the SDO_GEOMETRY data type. 418 | Per report from Bevan Jenkins. 419 | - Some point geometries were not translated properly. 420 | Per report from Bevan Jenkins. 421 | - Ignore SDO_GEOMETRY elements with zero SDO_ETYPE. 422 | According to Oracle, that is the correct behaviour. 423 | Per report from Bevan Jenkins. 424 | - Fix EXPLAIN (VERBOSE) for queries containing current_timestamp. 425 | This caused "ORA-30081: invalid data type for datetime/interval arithmetic". 426 | Noticed by "kkwhite". 427 | - Oracle TIMESTAMP(0) fields caused errors like: 428 | ERROR: invalid input syntax for type timestamp: "1977-06-09 18:00:00." 429 | Also, handling of dates and timestamps before Christ was broken. 430 | Report by "abiuan". 431 | 432 | Version 1.2.0, released 2015-01-03 433 | Enhancements: 434 | - Add support for a file "srid.map" to translate SRIDs between Oracle 435 | and PostGIS. 436 | - If the Oracle session has been terminated outside of a transaction, 437 | try to reconnect once. 438 | Idea by AVEN. 439 | 440 | Bugfixes: 441 | - Prepared statements with parameters can crash. 442 | Because of custom plans, this does not manifest until the query has been 443 | executed several times in PostgreSQL 9.2 and higher. 444 | Per report from Krzysztof Gorczyński and others. 445 | This bug was introduced in 1.1.0. 446 | 447 | Version 1.1.0, released 2014-12-03 448 | Enhancements: 449 | - Add efficient support for translating between Oracle SDO_GEOMETRY and 450 | PostGIS geometry. Supported geometry types are POINT, LINE, POLYGON, 451 | MULTIPOINT, MULTILINE and MULTIPOLYGON. 452 | Courtesy of Oslandia, implemented by Vincent Mora. 453 | - Add regression tests for improved quality. 454 | - Bind LOB data instead of LOB locators for INSERT and UPDATE. 455 | This simplifies the code and makes Oracle triggers on LOB columns 456 | behave as expected. 457 | 458 | Bugfixes: 459 | - Fix a bug introduced in 1.0.0 that leads to crashes when LOB columns 460 | are modified. 461 | - Fix several crashes when the foreign table has fewer or more columns 462 | than the Oracle table. 463 | - Fix a bug that caused "RETURNING " to return NULL for 464 | complex expressions. 465 | - Writing date or timestamp columns failed when DateStyle was not ISO. 466 | - Reading or writing negative INTERVAL DAY TO SECOND resulted in bad 467 | values because the string formats in PostgreSQL and Oracle differ. 468 | 469 | Version 1.0.0, released 2014-04-08 470 | Enhancements: 471 | - Add function oracle_diag(name) for diagnostic purposes. 472 | ATTENTION: Use "ALTER EXTENSION oracle_fdw UPDATE" when upgrading 473 | from a previous version of oracle_fdw. 474 | - Avoid unnecessary local filtering for pushed down WHERE clauses with 475 | internal parameters. 476 | - Add support for triggers on foreign tables for PostgreSQL 9.4. 477 | 478 | Bugfixes: 479 | - Fix logic error that keeps Oracle connections from closing. 480 | - Fix "cache lookup failed for type 0" in queries with string parameters. 481 | Per report from Adolfho Lopes. 482 | 483 | Version 0.9.10 (beta), released 2013-12-24 484 | Enhancements: 485 | - Add support for INSERT, DELETE and UPDATE. 486 | This is a major rewrite that might cause some destabilization in 487 | existing functionality. 488 | - Add new column option "key" to indicate primary key columns. 489 | This is needed for UPDATE and DELETE. 490 | - Add new table option "readonly" to forbid data modifying statements. 491 | - Improved transaction handling for data modifying statements. 492 | COMMIT, ROLLBACK and SAVEPOINT will work as expected. 493 | - Add paths for Oracle 12.1 to the Makefile. 494 | Patch by Guillaume Lelarge. 495 | 496 | Bugfixes: 497 | - Don't try to push down the division operator. 498 | That would produce incorrect results for numeric data types. 499 | 500 | Version 0.9.9 (beta), released 2013-08-07 501 | Enhancements: 502 | - Enable build with PostgreSQL 9.3. 503 | 504 | Bugfixes: 505 | - Fix error "ORA-01406: fetched column value was truncated" 506 | caused by timestamps with precision greater than 6. 507 | Per report from David E. Wheeler. 508 | - Fix crash with IN lists that do not entirely consist of constants. 509 | Per report from Wang Dong. 510 | - Fix handling of parameters during pushdown of WHERE conditions. 511 | The previous implementation returned incorrect results for certain 512 | queries like SELECT ... WHERE colname = (SELECT ...) 513 | ATTENTION: Since correct handling of parameters is not possible before 514 | PostgreSQL 9.2, query parameters will not be pushed down in PostgreSQL 9.1. 515 | This is a regression for cases where this happened to work. 516 | - Fix a logical error that can lead to incorrect Oracle WHERE clauses. 517 | - Fix a bug that can lead to the incorrect omission of a scan clause, 518 | leading to wrong results. 519 | 520 | Version 0.9.8 (beta), released 2012-10-16 521 | Enhancements: 522 | - Add support for pushdown of IN and NOT IN clauses in WHERE conditions. 523 | As suggested by Wang Dong. 524 | 525 | Bugfixes: 526 | - Add check to make sure that character string data are properly encoded. 527 | This is necessary because Oracle does not check this properly. 528 | Per report from David E. Wheeler. 529 | 530 | Version 0.9.7 (beta), released 2012-09-07 531 | Bugfixes: 532 | - Avoid failure to describe synonyms under certain conditions. 533 | ATTENTION: This constitutes a compatibility break: table and schema names 534 | now have to be exactly as they are in Oracle's catalogs, i.e. without 535 | double quotes and normally in uppercase. 536 | Per report from Bry Lo. 537 | - Add paths to Makefile so that we can build with Instant Client RPMs. 538 | Noticed by Andrew Theaker. 539 | - Fix a memory corruption bug that can lead to crashes, errors and 540 | wrong results. 541 | - Improve bad performance of "SELECT count(*)" on foreign tables. 542 | This is a simple workaround for the (not yet confirmed) 543 | Oracle bug 14562530. 544 | 545 | Version 0.9.6 (beta), released 2012-06-25 546 | Enhancements: 547 | - Support Oracle types LONG and LONG RAW. 548 | Introduce table option "max_long" (default 32767) to set the maximal 549 | length of such columns. 550 | 551 | Bugfixes: 552 | - Fix a bug that causes a server crash when the PostgreSQL session is 553 | terminated if the only statements involving oracle_fdw during that 554 | session were CREATE statements. 555 | Per report from Bry Lo. 556 | 557 | Version 0.9.5 (beta), released 2012-05-11 558 | Enhancements: 559 | - Support ANALYZE on foreign tables (from PostgreSQL 9.2 on). 560 | 561 | Bugfixes: 562 | - Fix a bug that leads to warnings and sometimes bad results if system 563 | columns of the foreign table are referenced. 564 | - Fix wrong column width estimates of plan_costs=on. 565 | 566 | Version 0.9.4 (beta), released 2012-03-19 567 | Enhancements: 568 | - Support the new foreign data wrapper API introduced in 9.2. 569 | In PostgreSQL 9.2 and above, WHERE conditions that get pushed down to 570 | Oracle will not be checked a second time. 571 | - Improve error messages for errors during conversion of Oracle data 572 | so that the problem can be diagnosed. 573 | 574 | Bugfixes: 575 | - Fix uninitialized value that caused intermittent server crashes. 576 | Per report from Bruno Voigt. 577 | - Rework the handling of errors and transactions. Now an error should not 578 | be able to cause an Oracle transaction to be left open. This also fixes 579 | a bug introduced in 0.9.3 that prevented Oracle errors from being 580 | reported as DETAIL message. Also, all foreign scans in one local query 581 | will now be executed within one Oracle transaction if they belong to 582 | the same Oracle session. 583 | - Rework memory management to exclude memory leaks under all circumstances. 584 | 585 | Version 0.9.3 (beta), released 2012-02-07 586 | Enhancements: 587 | - Add support for PostgreSQL data type "uuid". 588 | 589 | Bugfixes: 590 | - After an error message, calls to the foreign server result in this error: 591 | error connecting to Oracle: OCITransStart failed to start a transaction 592 | ORA-01453: SET TRANSACTION must be first statement of transaction 593 | The problem is that the previous transaction was not closed. 594 | This used to go unnoticed, the problem now becomes manifest because we 595 | explicitly start a serializable transaction. 596 | Per reports from Keith Fiske and Bruno Voigt. 597 | 598 | Version 0.9.2 (beta), released 2011-12-30 599 | Bugfixes: 600 | - Fix handling of Oracle BFILE columns. This was totally broken; attempts 601 | to select such columns resulted in the error message 602 | 'ORA-00932: inconsistent datatypes: expected %s got %s'. 603 | Bug report and patch by Dominique Legendre. 604 | - Use a serializable transaction in Oracle to make sure that consistent 605 | data are retrieved during a rescan. 606 | 607 | Version 0.9.1 (beta), released 2011-09-14 608 | Bugfixes: 609 | - Fix incorrect use of an automatic variable for binding timestamp parameters 610 | in Oracle. 611 | - Remove unnecessary lvalue casts. 612 | These violate the C standard and cause errors on gcc 4. 613 | Per report from Dominique Legendre. 614 | - Fix lack of support for dropped columns in foreign table. 615 | oracle_fdw incorrectly assumed that the n-th PostgreSQL column corresponds 616 | to the n-th Oracle column. This leads to confusion in the presence of 617 | dropped columns, which retain an entry in pg_attribute. 618 | Per report from Dominique Legendre. 619 | - Fix typo that caused wrong and negative sizes being assumed for longer 620 | Oracle columns. This led to palloc() errors and Oracle fetch errors. 621 | Per report from Dominique Legendre. 622 | 623 | Version 0.9 (beta), released 2011-08-25 624 | - initial release 625 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Portions Copyright (c) 2017-2025, CYBERTEC PostgreSQL International GmbH 2 | Portions Copyright (c) 2011-2017, Magistrat der Stadt Wien 3 | 4 | Permission to use, copy, modify, and distribute this software and its 5 | documentation for any purpose, without fee, and without a written agreement 6 | is hereby granted, provided that the above copyright notice and this paragraph 7 | and the following two paragraphs appear in all copies. 8 | 9 | IN NO EVENT SHALL THE COPYRIGHT HOLDER BE LIABLE TO ANY PARTY FOR 10 | DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING 11 | LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, 12 | EVEN IF THE COPYRIGHT HOLDER HAS BEEN ADVISED OF THE POSSIBILITY OF 13 | SUCH DAMAGE. 14 | 15 | THE COPYRIGHT HOLDER SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, 16 | BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR 17 | A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, 18 | AND THE COPYRIGHT HOLDER HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, 19 | SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 20 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | MODULE_big = oracle_fdw 2 | OBJS = oracle_fdw.o oracle_utils.o oracle_gis.o 3 | EXTENSION = oracle_fdw 4 | DATA = oracle_fdw--1.2.sql oracle_fdw--1.0--1.1.sql oracle_fdw--1.1--1.2.sql 5 | DOCS = README.oracle_fdw 6 | REGRESS = oracle_fdw oracle_gis oracle_import oracle_join 7 | 8 | # try to find Instant Client installations installed in standard paths 9 | FIND_INCLUDE := $(wildcard /usr/include/oracle/*/client64 /usr/include/oracle/*/client) 10 | FIND_LIBDIRS := $(wildcard /usr/lib/oracle/*/client64/lib /usr/lib/oracle/*/client/lib) 11 | 12 | FIND_CPPFLAGS = $(foreach DIR,$(FIND_INCLUDE),-I$(DIR)) 13 | FIND_LDFLAGS = $(foreach DIR,$(FIND_LIBDIRS),-L$(DIR)) 14 | 15 | # add include and library paths for both Instant Client and regular Client 16 | PG_CPPFLAGS = -I"$(ORACLE_HOME)/sdk/include" -I"$(ORACLE_HOME)/oci/include" -I"$(ORACLE_HOME)/rdbms/public" -I"$(ORACLE_HOME)/" $(FIND_CPPFLAGS) 17 | SHLIB_LINK = -L"$(ORACLE_HOME)/" -L"$(ORACLE_HOME)/bin" -L"$(ORACLE_HOME)/lib" -L"$(ORACLE_HOME)/lib/amd64" $(FIND_LDFLAGS) -l$(ORACLE_SHLIB) 18 | 19 | # don't build LLVM byte code 20 | override with_llvm := no 21 | 22 | ifdef NO_PGXS 23 | subdir = contrib/oracle_fdw 24 | top_builddir = ../.. 25 | include $(top_builddir)/src/Makefile.global 26 | include $(top_srcdir)/contrib/contrib-global.mk 27 | else 28 | PG_CONFIG = pg_config 29 | PGXS := $(shell $(PG_CONFIG) --pgxs) 30 | include $(PGXS) 31 | endif 32 | 33 | # Oracle's shared library is oci.dll on Windows and libclntsh elsewhere 34 | ifeq ($(PORTNAME),win32) 35 | ORACLE_SHLIB=oci 36 | else 37 | ifeq ($(PORTNAME),cygwin) 38 | ORACLE_SHLIB=oci 39 | else 40 | ORACLE_SHLIB=clntsh 41 | endif 42 | endif 43 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | README.oracle_fdw -------------------------------------------------------------------------------- /README.oracle_fdw: -------------------------------------------------------------------------------- 1 | Foreign Data Wrapper for Oracle 2 | =============================== 3 | 4 | oracle_fdw is a PostgreSQL extension that provides a Foreign Data Wrapper for 5 | easy and efficient access to Oracle databases, including pushdown of WHERE 6 | conditions and required columns as well as comprehensive EXPLAIN support. 7 | 8 | This README contains the following sections: 9 | 10 | 1. [Cookbook](#1-cookbook) 11 | 2. [Objects created by the extension](#2-objects-created-by-the-extension) 12 | 3. [Options](#3-options) 13 | 4. [Usage](#4-usage) 14 | 5. [Installation Requirements](#5-installation-requirements) 15 | 6. [Installation](#6-installation) 16 | 7. [Internals](#7-internals) 17 | 8. [Problems](#8-problems) 18 | 9. [Support](#9-support) 19 | 20 | oracle_fdw was written by Laurenz Albe, with notable contributions from 21 | Vincent Mora of Oslandia and Tatsuro Yamada of the NTT OSS Center. 22 | 23 | Special thanks to Christian Ullrich for ongoing help with Windows. 24 | 25 | 1 Cookbook 26 | ========== 27 | 28 | This is a simple example how to use oracle_fdw. 29 | More detailed information will be provided in the sections 30 | [Options](#3-options) and [Usage](#4-usage). You should also read the 31 | [PostgreSQL documentation on foreign data][fd] and the commands referenced 32 | there. 33 | 34 | [fd]: https://www.postgresql.org/docs/current/static/ddl-foreign-data.html 35 | 36 | For the sake of this example, let's assume you can connect as operating system 37 | user `postgres` (or whoever starts the PostgreSQL server) with the following 38 | command: 39 | 40 | sqlplus orauser/orapwd@//dbserver.mydomain.com:1521/ORADB 41 | 42 | That means that the Oracle client and the environment is set up correctly. 43 | I also assume that oracle_fdw has been compiled and installed (see the 44 | [Installation](#6-installation) section). 45 | 46 | We want to access a table defined like this: 47 | 48 | 49 | SQL> DESCRIBE oratab 50 | Name Null? Type 51 | ------------------------------- -------- ------------ 52 | ID NOT NULL NUMBER(5) 53 | TEXT VARCHAR2(30) 54 | FLOATING NOT NULL NUMBER(7,2) 55 | 56 | 57 | Then configure oracle_fdw as PostgreSQL superuser like this: 58 | 59 | pgdb=# CREATE EXTENSION oracle_fdw; 60 | pgdb=# CREATE SERVER oradb FOREIGN DATA WRAPPER oracle_fdw 61 | OPTIONS (dbserver '//dbserver.mydomain.com:1521/ORADB'); 62 | 63 | (You can use other naming methods or local connections, see the description of 64 | the option **dbserver** below.) 65 | 66 | It is a good idea to use a superuser only where really necessary, so let's 67 | allow a normal user to use the foreign server (this is not required for the 68 | example to work, but I recommend it): 69 | 70 | pgdb=# GRANT USAGE ON FOREIGN SERVER oradb TO pguser; 71 | 72 | Then you can connect to PostgreSQL as `pguser` and define: 73 | 74 | pgdb=> CREATE USER MAPPING FOR pguser SERVER oradb 75 | OPTIONS (user 'orauser', password 'orapwd'); 76 | 77 | (You can use external authentication to avoid storing Oracle passwords; 78 | see below.) 79 | 80 | pgdb=> CREATE FOREIGN TABLE oratab ( 81 | id integer OPTIONS (key 'true') NOT NULL, 82 | text character varying(30), 83 | floating double precision NOT NULL 84 | ) SERVER oradb OPTIONS (schema 'ORAUSER', table 'ORATAB'); 85 | 86 | (Remember that table and schema name -- the latter is optional -- must 87 | normally be in uppercase.) 88 | 89 | Now you can use the table like a regular PostgreSQL table. 90 | 91 | 2 Objects created by the extension 92 | ================================== 93 | 94 | FUNCTION oracle_fdw_handler() RETURNS fdw_handler 95 | FUNCTION oracle_fdw_validator(text[], oid) RETURNS void 96 | 97 | These functions are the handler and the validator function necessary to create 98 | a foreign data wrapper. 99 | 100 | FOREIGN DATA WRAPPER oracle_fdw 101 | HANDLER oracle_fdw_handler 102 | VALIDATOR oracle_fdw_validator 103 | 104 | The extension automatically creates a foreign data wrapper named `oracle_fdw`. 105 | Normally that's all you need, and you can proceed to define foreign servers. 106 | You can create additional Oracle foreign data wrappers, for example if you 107 | need to set the **nls_lang** option (you can alter the existing `oracle_fdw` 108 | wrapper, but all modifications will be lost after a dump/restore). 109 | 110 | FUNCTION oracle_close_connections() RETURNS void 111 | 112 | This function can be used to close all open Oracle connections in this session. 113 | See the [Usage](#4-usage) section for further description. 114 | 115 | FUNCTION oracle_diag(name DEFAULT NULL) RETURNS text 116 | 117 | This function is useful for diagnostic purposes only. 118 | It will return the versions of oracle_fdw, PostgreSQL server and Oracle client. 119 | If called with no argument or NULL, it will additionally return the values of 120 | some environment variables used for establishing Oracle connections. 121 | If called with the name of a foreign server, it will additionally return 122 | the Oracle server version. 123 | 124 | FUNCTION oracle_execute(server name, stmt text) RETURNS void 125 | 126 | This function can be used to execute arbitrary SQL statements on the remote 127 | Oracle server. That will only work with statements that do not return results 128 | (typically DDL statements). 129 | 130 | Be careful when using this function, since it might disturb the transaction 131 | management of oracle_fdw. Remember that running a DDL statement in Oracle 132 | will issue an implicit COMMIT. 133 | You are best advised to use this function outside of multi-statement 134 | transactions. 135 | 136 | 3 Options 137 | ========= 138 | 139 | Foreign data wrapper options 140 | ---------------------------- 141 | 142 | (Caution: If you modify the default foreign data wrapper `oracle_fdw`, 143 | any changes will be lost upon dump/restore. Create a new foreign data wrapper 144 | if you want the options to be persistent. The SQL script shipped with the 145 | software contains a CREATE FOREIGN DATA WRAPPER statement you can use.) 146 | 147 | - **nls_lang** (optional) 148 | 149 | Sets the NLS_LANG environment variable for Oracle to this value. 150 | NLS_LANG is in the form "language_territory.charset" (for example 151 | AMERICAN_AMERICA.AL32UTF8). This must match your database encoding. 152 | When this value is not set, oracle_fdw will automatically do the right 153 | thing if it can and issue a warning if it cannot. Set this only if you 154 | know what you are doing. See the [Problems](#8-problems) section. 155 | 156 | Foreign server options 157 | ---------------------- 158 | 159 | - **dbserver** (required) 160 | 161 | The Oracle database connection string for the remote database. 162 | This can be in any of the forms that Oracle supports as long as your 163 | Oracle client is configured accordingly. 164 | Set this to an empty string for local ("BEQUEATH") connections. 165 | 166 | - **isolation_level** (optional, defaults to `serializable`) 167 | 168 | The transaction isolation level to use at the Oracle database. 169 | The value can be `serializable`, `read_committed` or `read_only`. (READ ONLY 170 | actually is a transaction access mode, not an isolation level, but we ignore 171 | that distinction here.) 172 | 173 | Note that the Oracle table can be queried more than once during a single 174 | PostgreSQL statement (for example, during a nested loop join). To make 175 | sure that no inconsistencies caused by race conditions with concurrent 176 | transactions can occur, the transaction isolation level must guarantee 177 | read stability. 178 | This is only guaranteed with Oracle's SERIALIZABLE or READ ONLY isolation 179 | levels. 180 | 181 | Unfortunately Oracle's implementation of SERIALIZABLE is rather bad and 182 | causes serialization errors (ORA-08177) in unexpected situations, like 183 | inserts into the table. 184 | Using READ COMMITTED transactions works around this problem, but **there 185 | is a risk of inconsistencies**. If you want to use it, check your 186 | execution plans if the foreign scan could be executed more than once. 187 | 188 | - **nchar** (boolean, optional, defaults to `off`) 189 | 190 | Setting this option to `on` chooses a more expensive character conversion 191 | on the Oracle side. This is required if Oracle tables have NCHAR or 192 | NVARCHAR2 columns that contain characters that cannot be represented in the 193 | Oracle database character set. 194 | 195 | Setting `nchar` to `on` has a noticable performance impact, and it causes 196 | ORA-01461 errors with UPDATE statements that set strings over 2000 bytes 197 | (or 16383 if you have MAX_STRING_SIZE = EXTENDED). 198 | This error seems to be an Oracle bug. 199 | 200 | - **set_timezone** (boolean, optional, defaults to `off`) 201 | 202 | Setting this option to `on` sets the Oracle session time zone to the current 203 | value of the PostgreSQL parameter `timezone` when the connection to Oracle 204 | is made. This is only useful if you plan to use Oracle columns of type 205 | TIMESTAMP WITH LOCAL TIME ZONE and want to translate them to `timestamp 206 | without time zone` in PostgreSQL. 207 | 208 | Note that if you change `timezone` after the Oracle connection has been 209 | established, oracle_fdw won't change the Oracle session time zone. You can 210 | call `oracle_close_connections()` in that case, so that a new connection is 211 | opened the next time you access a foreign table. 212 | 213 | If Oracle does not recognize the time zone, connections will fail with an 214 | error like 215 | 216 | ORA-01882: timezone region not found 217 | 218 | In that case, either use a different `timezone` or leave the option set `off` 219 | and set the environment variable ORA_SDTZ to an appropriate value in the 220 | environment of the PostgreSQL server. 221 | 222 | User mapping options 223 | -------------------- 224 | 225 | - **user** (required) 226 | 227 | The Oracle user name for the session. 228 | Set this to an empty string for *external authentication* if you don't 229 | want to store Oracle credentials in the PostgreSQL database (one simple way 230 | is to use an *external password store*). 231 | 232 | - **password** (required) 233 | 234 | The password for the Oracle user. 235 | 236 | Foreign table options 237 | --------------------- 238 | 239 | - **table** (required) 240 | 241 | The Oracle table name. This name must be written exactly as it occurs in 242 | Oracle's system catalog, so normally consist of uppercase letters only. 243 | 244 | To define a foreign table based on an arbitrary Oracle query, set this 245 | option to the query enclosed in parentheses, e.g. 246 | 247 | OPTIONS (table '(SELECT col FROM tab WHERE val = ''string'')') 248 | 249 | Do not set the **schema** option in this case. 250 | INSERT, UPDATE and DELETE will work on foreign tables defined on simple 251 | queries; if you want to avoid that (or confusing Oracle error messages 252 | for more complicated queries), use the table option **readonly**. 253 | 254 | - **dblink** (optional) 255 | 256 | The Oracle database link through which the table is accessed. This name 257 | must be written exactly as it occurs in Oracle's system catalog, so 258 | normally consist of uppercase letters only. 259 | 260 | - **schema** (optional) 261 | 262 | The table's schema (or owner). Useful to access tables that do not belong 263 | to the connecting Oracle user. This name must be written exactly as it 264 | occurs in Oracle's system catalog, so normally consist of uppercase letters 265 | only. 266 | 267 | - **max_long** (optional, defaults to "32767") 268 | 269 | The maximal length of any LONG, LONG RAW and XMLTYPE columns in the Oracle 270 | table. Possible values are integers between 1 and 1073741823 (the maximal 271 | size of a `bytea` in PostgreSQL). This amount of memory will be allocated 272 | at least twice, so large values will consume a lot of memory. 273 | If **max_long** is less than the length of the longest value retrieved, 274 | you will receive the error message `ORA-01406: fetched column value was 275 | truncated`. 276 | 277 | - **readonly** (optional, defaults to "false") 278 | 279 | INSERT, UPDATE and DELETE is only allowed on tables where this option is 280 | not set to yes/on/true. 281 | 282 | - **sample_percent** (optional, defaults to "100") 283 | 284 | This option only influences ANALYZE processing and can be useful to 285 | ANALYZE very large tables in a reasonable time. 286 | 287 | The value must be between 0.000001 and 100 and defines the percentage of 288 | Oracle table blocks that will be randomly selected to calculate PostgreSQL 289 | table statistics. This is accomplished using the `SAMPLE BLOCK (x)` 290 | clause in Oracle. 291 | 292 | ANALYZE will fail with ORA-00933 for tables defined with Oracle queries and 293 | may fail with ORA-01446 for tables defined with complex Oracle views. 294 | 295 | - **prefetch** (optional, defaults to "50") 296 | 297 | Sets the number of rows that will be fetched with a single round-trip between 298 | PostgreSQL and Oracle during a foreign table scan. The value must be between 299 | 1 and 10240. 300 | 301 | Higher values can speed up performance, but will use more memory on the 302 | PostgreSQL server and can lead to out-of-memory errors there. High values 303 | usually won't offer any benefit unless the table rows are very small. Be 304 | careful with high values; you have been warned. 305 | 306 | Note that there is no prefetching if the Oracle table contains columns of 307 | the type `MDSYS.SDO_GEOMETRY`. 308 | 309 | - **lob_prefetch** (optional, defaults to "1048576") 310 | 311 | Sets the number of bytes that are prefetched for BLOB, CLOB and BFILE values. 312 | LOBs that exceed that size will require additional round trips between 313 | PostgreSQL and Oracle, so setting this value bigger than the size of your 314 | typical LOB will be good for performance. Choosing bigger values for this 315 | option can allocate more memory on the server side, but will boost performance 316 | for large LOBs. 317 | 318 | Column options 319 | -------------- 320 | 321 | - **key** (optional, defaults to "false") 322 | 323 | If set to yes/on/true, the corresponding column on the foreign Oracle table 324 | is considered a primary key column. 325 | For UPDATE and DELETE to work, you must set this option on all columns 326 | that belong to the table's primary key. 327 | 328 | - **strip_zeros** (optional, defaults to "false") 329 | 330 | If set to yes/on/true, ASCII 0 characters will be removed from the string 331 | during transfer. Such characters are valid in Oracle but not in PostgreSQL, 332 | so they will cause an error when read by oracle_fdw. This option only 333 | make sense for `character`, `character varying` and `text` columns. 334 | 335 | 4 Usage 336 | ======= 337 | 338 | Oracle permissions 339 | ------------------ 340 | 341 | The Oracle user will obviously need CREATE SESSION privilege and the right 342 | to select from the table or view in question. Note that oracle_fdw accesses 343 | the Oracle table at query planning time to get its definition. This happens 344 | *before* permissions on the foreign table are checked. Consequently, you may 345 | receive an Oracle error if you try to access a foreign table on which you 346 | have no permissions in PostgreSQL. This is expected and no security problem. 347 | 348 | For EXPLAIN VERBOSE the user will also need SELECT privileges on V$SQL and 349 | V$SQL_PLAN. 350 | 351 | Connections 352 | ----------- 353 | 354 | oracle_fdw caches Oracle connections because it is expensive to create an 355 | Oracle session for each individual query. All connections are automatically 356 | closed when the PostgreSQL session ends. 357 | 358 | The function `oracle_close_connections()` can be used to close all cached 359 | Oracle connections. This can be useful for long-running sessions that don't 360 | access foreign tables all the time and want to avoid blocking the resources 361 | needed by an open Oracle connection. 362 | You cannot call this function inside a transaction that modifies Oracle data. 363 | 364 | Columns 365 | ------- 366 | 367 | When you define a foreign table, the columns of the Oracle table are mapped 368 | to the PostgreSQL columns in the order of their definition. 369 | 370 | oracle_fdw will only include those columns in the Oracle query that are 371 | actually needed by the PostgreSQL query. 372 | 373 | The PostgreSQL table can have more or less columns than the Oracle table. 374 | If it has more columns, and these columns are used, you will receive a warning 375 | and NULL values will be returned. 376 | 377 | If you want to UPDATE or DELETE, make sure that the `key` option is set on all 378 | columns that belong to the table's primary key. Failure to do so will result 379 | in errors. 380 | 381 | Data types 382 | ---------- 383 | 384 | You must define the PostgreSQL columns with data types that oracle_fdw can 385 | translate (see the conversion table below). This restriction is only enforced 386 | if the column actually gets used, so you can define "dummy" columns for 387 | untranslatable data types as long as you don't access them (this trick only 388 | works with SELECT, not when modifying foreign data). If an Oracle value 389 | exceeds the size of the PostgreSQL column (e.g., the length of a varchar 390 | column or the maximal integer value), you will receive a runtime error. 391 | 392 | These conversions are automatically handled by oracle_fdw: 393 | 394 | Oracle type | Possible PostgreSQL types 395 | -------------------------+-------------------------------------------------- 396 | CHAR | char, varchar, text 397 | NCHAR | char, varchar, text 398 | VARCHAR | char, varchar, text 399 | VARCHAR2 | char, varchar, text, json 400 | NVARCHAR2 | char, varchar, text 401 | CLOB | char, varchar, text, json 402 | NCLOB | char, varchar, text, json 403 | LONG | char, varchar, text 404 | RAW | uuid, bytea 405 | BLOB | bytea 406 | BFILE | bytea (read-only) 407 | LONG RAW | bytea 408 | NUMBER | numeric, float4, float8, char, varchar, text 409 | NUMBER(n,m) with m<=0 | numeric, float4, float8, int2, int4, int8, 410 | | boolean, char, varchar, text 411 | FLOAT | numeric, float4, float8, char, varchar, text 412 | BINARY_FLOAT | numeric, float4, float8, char, varchar, text 413 | BINARY_DOUBLE | numeric, float4, float8, char, varchar, text 414 | DATE | date, timestamp, timestamptz, char, varchar, text 415 | TIMESTAMP | date, timestamp, timestamptz, char, varchar, text 416 | TIMESTAMP WITH TIME ZONE | date, timestamp, timestamptz, char, varchar, text 417 | TIMESTAMP WITH | date, timestamp, timestamptz, char, varchar, text 418 | LOCAL TIME ZONE | 419 | INTERVAL YEAR TO MONTH | interval, char, varchar, text 420 | INTERVAL DAY TO SECOND | interval, char, varchar, text 421 | XMLTYPE | xml, char, varchar, text 422 | MDSYS.SDO_GEOMETRY | geometry (see "PostGIS support" below) 423 | 424 | If a NUMBER is converted to a boolean, 0 means `false`, everything else `true`. 425 | 426 | Inserting or updating XMLTYPE only works with values that do not exceed the 427 | maximum length of the VARCHAR2 data type (4000 or 32767, depending on the 428 | `MAX_STRING_SIZE` parameter). 429 | 430 | If you want to convert TIMESTAMP WITH LOCAL TIME ZONE to `timestamp`, consider 431 | setting the `set_timezone` option on the foreign server. 432 | 433 | If you want to convert TIMESTAMP WITH LOCAL TIME ZONE to `timestamp`, consider 434 | setting the `set_timezone` option on the foreign server. 435 | 436 | If you need conversions exceeding the above, define an appropriate view in 437 | Oracle or PostgreSQL. 438 | 439 | WHERE conditions and ORDER BY clauses 440 | ------------------------------------- 441 | 442 | PostgreSQL will use all applicable parts of the WHERE clause as a filter 443 | for the scan. The Oracle query that oracle_fdw constructs will contain a WHERE 444 | clause corresponding to these filter criteria whenever such a condition can 445 | safely be translated to Oracle SQL. This feature, also known as *push-down 446 | of WHERE clauses*, can greatly reduce the number of rows retrieved from Oracle 447 | and may enable Oracle's optimizer to choose a good plan for accessing the 448 | required tables. 449 | 450 | Similarly, ORDER BY clauses will be pushed down to Oracle wherever possible. 451 | Note that no ORDER BY condition that sorts by a character string will be 452 | pushed down as the sort orders in PostgreSQL and Oracle cannot be guaranteed 453 | to be the same. 454 | 455 | To make use of that, try to use simple conditions for the foreign table. 456 | Choose PostgreSQL column data types that correspond to Oracle's types, 457 | because otherwise conditions cannot be translated. 458 | 459 | The expressions `now()`, `transaction_timestamp()`, `current_timestamp`, 460 | `current_date` and `localtimestamp` will be translated correctly. 461 | 462 | The output of EXPLAIN will show the Oracle query used, so you can see which 463 | conditions were translated to Oracle and how. 464 | 465 | Joins between foreign tables 466 | ---------------------------- 467 | 468 | From PostgreSQL 9.6 on, oracle_fdw can push down joins to the Oracle server, 469 | that is, a join between two foreign tables will lead to a single Oracle query 470 | that performs the join on the Oracle side. 471 | 472 | There are some restrictions when this can happen: 473 | 474 | - Both tables must be defined on the same foreign server. 475 | - Joins between three or more tables won't be pushed down. 476 | - The join must be in a SELECT statement. 477 | - oracle_fdw must be able to push down all join conditions and WHERE clauses. 478 | - Cross joins without join conditions are not pushed down. 479 | - If a join is pushed down, ORDER BY clauses will not be pushed down. 480 | 481 | It is important that table statistics for both foreign tables have been 482 | collected with ANALYZE for PostgreSQL to determine the best join strategy. 483 | 484 | Modifying foreign data 485 | ---------------------- 486 | 487 | oracle_fdw supports INSERT, UPDATE and DELETE on foreign tables. 488 | This is allowed by default (also in databases upgraded from an earlier 489 | PostgreSQL release) and can be disabled by setting the **readonly** 490 | table option. 491 | 492 | For UPDATE and DELETE to work, the columns corresponding to the primary 493 | key columns of the Oracle table must have the **key** column option set. 494 | These columns are used to identify a foreign table row, so make sure that 495 | the option is set on *all* columns that belong to the primary key. 496 | 497 | If you omit a foreign table column during INSERT, that column is set to 498 | the value defined in the DEFAULT clause on the PostgreSQL foreign table 499 | (or NULL if there is no DEFAULT clause). DEFAULT clauses on the 500 | corresponding Oracle columns are not used. 501 | If the PostgreSQL foreign table does not include all columns of the 502 | Oracle table, the Oracle DEFAULT clauses will be used for the columns not 503 | included in the foreign table definition. 504 | 505 | The RETURNING clause on INSERT, UPDATE and DELETE is supported except 506 | for columns with Oracle data types LONG and LONG RAW (Oracle doesn't support 507 | these data types in the RETURNING clause). 508 | 509 | Triggers on foreign tables are supported from PostgreSQL 9.4. 510 | Triggers defined with AFTER and FOR EACH ROW require that the foreign table 511 | has no columns with Oracle data type LONG or LONG RAW. This is because 512 | such triggers make use of the RETURNING clause mentioned above. 513 | 514 | While modifying foreign data works, the performance is not particularly 515 | good, specifically when many rows are affected, because (owing to the way 516 | foreign data wrappers work) each row has to be treated individually. 517 | 518 | Transactions are forwarded to Oracle, so BEGIN, COMMIT, ROLLBACK and 519 | SAVEPOINT work as expected. Prepared statements involving Oracle are 520 | not supported. See the [Internals](#7-internals) section for details. 521 | 522 | Since oracle_fdw uses serialized transactions by default, it is possible that 523 | data modifying statements lead to a serialization failure: 524 | 525 | ORA-08177: can't serialize access for this transaction 526 | 527 | This can happen if concurrent transactions modify the table and gets more 528 | likely in long running transactions. Such errors can be identified by their 529 | SQLSTATE (40001). An application using oracle_fdw should retry transactions 530 | that fail with this error. 531 | 532 | It is possible to use a different transaction isolation level, see 533 | [Foreign server options](#foreign-server-options) for a discussion. 534 | 535 | EXPLAIN 536 | ------- 537 | 538 | PostgreSQL's EXPLAIN will show the query that is actually issued to Oracle. 539 | EXPLAIN VERBOSE will show Oracle's execution plan (that will not work with 540 | Oracle server 9i or older, see [Problems](#8-problems)). 541 | 542 | ANALYZE 543 | ------- 544 | 545 | You can use ANALYZE to gather statistics on a foreign table. 546 | This is supported by oracle_fdw. 547 | 548 | Without statistics, PostgreSQL has no way to estimate the row count for 549 | queries on a foreign table, which can cause bad execution plans to be chosen. 550 | 551 | PostgreSQL will *not* automatically gather statistics for foreign tables 552 | with the autovacuum daemon like it does for normal tables, so it is 553 | particularly important to run ANALYZE on foreign tables after creation 554 | and whenever the remote table has changed significantly. 555 | 556 | Keep in mind that analyzing an Oracle foreign table will result in a full 557 | sequential table scan. You can use the table option **sample_percent** to 558 | speed this up by using only a sample of the Oracle table. 559 | 560 | PostGIS support 561 | --------------- 562 | 563 | The data type `geometry` is only available when PostGIS is installed. 564 | 565 | The only supported geometry types are POINT, LINE, POLYGON, 566 | MULTIPOINT, MULTILINE and MULTIPOLYGON in two and three dimensions. 567 | Empty PostGIS geometries are not supported because they have no equivalent 568 | in Oracle Spatial. 569 | 570 | NULL values for Oracle SRID will be converted to 0 and vice versa. 571 | For other conversions between Oracle SRID and PostGIS SRID, create a file 572 | `srid.map` in the PostgreSQL `share` directory. Each line of this file 573 | shall contain an Oracle SRID and the corresponding PostGIS SRID, separated 574 | by whitespace. Keep the file small for good performance. 575 | 576 | Support for IMPORT FOREIGN SCHEMA 577 | --------------------------------- 578 | 579 | From PostgreSQL 9.5 on, IMPORT FOREIGN SCHEMA is supported to bulk import 580 | table definitions for all tables in an Oracle schema. 581 | In addition to the documentation of IMPORT FOREIGN SCHEMA, consider the 582 | following: 583 | 584 | - IMPORT FOREIGN SCHEMA will create foreign tables for all objects found in 585 | ALL_TAB_COLUMNS. That includes tables, views and materialized views, 586 | but not synonyms. 587 | 588 | - These are the supported options for IMPORT FOREIGN SCHEMA: 589 | 590 | - **case**: controls case folding for table and column names during import 591 | 592 | The possible values are: 593 | - `keep`: leave the names as they are in Oracle, usually in upper case. 594 | - `lower`: translate all table and column names to lower case. 595 | - `smart`: only translate names that are all upper case in Oracle 596 | (this is the default). 597 | 598 | - **collation**: the collation used for case folding for the `lower` and 599 | `smart` options of **case** 600 | 601 | The default value is `default` which is the database's default collation. 602 | Only collations in the `pg_catalog` schema are supported. 603 | See the `collname` values in the `pg_collation` catalog for a list of 604 | possible values. 605 | 606 | - **dblink**: the Oracle database link through which the schema is accessed 607 | 608 | This name must be written exactly as it occurs in Oracle's system catalog, 609 | so normally consist of uppercase letters only. 610 | 611 | - **readonly**: sets the **readonly** option on all imported tables 612 | 613 | See the [Options](#3-options) section for details. 614 | 615 | - **skip_tables** (default `false`): don't import tables 616 | 617 | - **skip_views** (default `false`): don't import views 618 | 619 | - **skip_matviews** (default `false`): don't import materialized views 620 | 621 | - **max_long**: sets the **max_long** option on all imported tables 622 | 623 | See the [Options](#3-options) section for details. 624 | 625 | - **sample_percent**: sets the **sample_percent** option 626 | on all imported tables 627 | 628 | See the [Options](#3-options) section for details. 629 | 630 | - **prefetch**: sets the **prefetch** option on all imported tables 631 | 632 | See the [Options](#3-options) section for details. 633 | 634 | - **lob_prefetch**: sets the **lob_prefetch** option on all imported tables 635 | 636 | See the [Options](#3-options) section for details. 637 | 638 | - **nchar**: sets the **nchar** option on all imported tables 639 | 640 | See the [Options](#3-options) section for details. 641 | 642 | - **set_timezone**: sets the **set_timezone** option on all imported tables 643 | 644 | See the [Options](#3-options) section for details. 645 | 646 | - The Oracle schema name must be written exactly as it is in Oracle, so 647 | normally in upper case. Since PostgreSQL translates names to lower case 648 | before processing, you must protect the schema name with double quotes 649 | (for example `"SCOTT"`). 650 | 651 | - Table names in the LIMIT TO or EXCEPT clause must be written as they 652 | will appear in PostgreSQL after the case folding described above. 653 | 654 | Note that IMPORT FOREIGN SCHEMA does not work with Oracle server 8i; 655 | see the [Problems](#8-problems) section for details. 656 | 657 | 5 Installation Requirements 658 | =========================== 659 | 660 | oracle_fdw should compile and run on any platform supported by PostgreSQL and 661 | Oracle client, although I could only test it on Linux and Windows. 662 | 663 | PostgreSQL 9.3 or better is required. 664 | 665 | Due to API breaks in PostgreSQL minor releases, the following PostgreSQL 666 | versions cannot be used: 667 | 668 | - 9.6.0 to 9.6.8 669 | - 10.0 to 10.3 670 | - 11.0 to 11.10 671 | - 12.0 to 12.5 672 | - 13.0 to 13.9 673 | - 14.0 to 14.6 674 | - 15.0 to 15.1 675 | 676 | As always, you should be running the latest minor release for whatever 677 | PostgreSQL version you are using. 678 | 679 | oracle_fdw is written for standard open source PostgreSQL. 680 | Forks of PostgreSQL, such as "PostgresPro" and "Postgres-XL", are likely to 681 | be incompatible. 682 | If you want to try it nonetheless, you'll have to build oracle_fdw from source. 683 | If you encounter problems while using such a PostgreSQL-derived server, 684 | please try with the original version before reporting an issue. 685 | 686 | Oracle client version 11.2 or better is required. 687 | oracle_fdw can be built and used with Oracle Instant Client as well as with 688 | Oracle Client and Server installations installed with Universal Installer. 689 | Binaries compiled with Oracle Client 11 can be used with later client versions 690 | without recompilation or relink. 691 | 692 | The supported Oracle server versions depend on the used client version (see the 693 | Oracle Client/Server Interoperability Matrix in Oracle Support document 694 | 207303.1). PostgreSQL and Oracle need to have the same architecture. 695 | For example, you cannot have 32-bit software for the one and 64-bit software 696 | for the other. 697 | 698 | It is advisable to use the latest Patch Set on both Oracle client and server, 699 | particularly with desupported Oracle versions. 700 | For a list of Oracle bugs that are known to affect oracle_fdw's usability, 701 | see the [Problems](#8-problems) section. 702 | Consult the oracle_fdw Wiki (https://github.com/laurenz/oracle_fdw/wiki) 703 | for tips about Oracle installation and configuration and share your own 704 | knowledge there. 705 | 706 | 6 Installation 707 | ============== 708 | 709 | If you are using a binary distribution of oracle_fdw, skip to "Installing the 710 | extension" below. Additional hints for installing oracle_fdw can be found 711 | on the [Wiki](https://github.com/laurenz/oracle_fdw/wiki). 712 | 713 | Building oracle_fdw on platforms other than Windows: 714 | ---------------------------------------------------- 715 | 716 | oracle_fdw has been written as a PostgreSQL extension and uses the Extension 717 | Building Infrastructure PGXS on all platforms except Windows. It should be 718 | easy to install. For building on Windows, see the next section. 719 | 720 | You will need PostgreSQL headers and PGXS installed. If your PostgreSQL was 721 | installed with binary packages, install the "development" package. Make sure 722 | you have all operating system packages installed that were needed to build 723 | PostgreSQL (on Redhat-based systems, this may include "redhat-rpm-config"). 724 | 725 | You need to install Oracle's C header files as well (SDK package for Instant 726 | Client). If you use the Instant Client ZIP files provided by Oracle, 727 | you may have to create a symbolic link from `libclntsh.so` to the actual shared 728 | library file yourself (normally, the SDK package does that). 729 | 730 | Make sure that PostgreSQL is configured `--without-ldap` (at least the server). 731 | See the [Problems](#8-problems) section. 732 | 733 | Make sure that `pg_config` is in the PATH (test with `pg_config --pgxs`). 734 | Set the environment variable ORACLE_HOME to the location of the Oracle 735 | installation. 736 | 737 | Unpack the source code of oracle_fdw and change into the directory. 738 | Then the software installation should be as simple as: 739 | 740 | $ make 741 | $ make install 742 | 743 | For the second step you need write permission on the directories where 744 | PostgreSQL is installed. 745 | 746 | If you want to build oracle_fdw in a source tree of PostgreSQL, use 747 | 748 | $ make NO_PGXS=1 749 | 750 | Building oracle_fdw on Windows: 751 | ------------------------------- 752 | 753 | To build oracle_fdw on Windows, you need: 754 | 755 | - PostgreSQL headers and libraries. These can be found in the PostgreSQL 756 | installation directory. 757 | - Oracle headers and libraries (SDK package for Instant Client). 758 | - Microsoft Visual Studio 2013 or later. 759 | 760 | To build, either open `oracle_fdw\msvc\oracle_fdw.sln` in the IDE, or: 761 | 762 | - Open a development command prompt (either x86 or x64 depending on your 763 | PostgreSQL installation) and change to the `oracle_fdw\msvc` directory. 764 | - Run (single command line): 765 | 766 | > msbuild oracle_fdw.sln /p:Configuration=(Debug or Release) ^ 767 | /p:Platform=(Win32 or x64) ^ 768 | /p:OracleClient=(path to Oracle Client/SDK) ^ 769 | /p:PostgreSQL=(path to PostgreSQL installation) 770 | 771 | (The "^"s are line continuations; you can just put everything on a single 772 | line instead.) 773 | 774 | When the build is complete, you will find `oracle_fdw.dll` in a subdirectory 775 | named for your build options, e.g. `x64\Release`. 776 | 777 | If you use Visual Studio 2015 or later and you get errors about missing 778 | header files including `sys/types.h`, you must install the Universal CRT 779 | SDK (part of Visual Studio). 780 | 781 | Copy `oracle_fdw.dll` into the PostgreSQL library directory and copy 782 | `oracle_fdw.control` and the SQL files into the `extension` subdirectory of 783 | the PostgreSQL share directory. 784 | To find those directories, you can use `pg_config --libdir` and 785 | `pg_config --sharedir`. 786 | 787 | Installing the extension: 788 | ------------------------- 789 | 790 | Make sure that the oracle_fdw shared library is installed in the PostgreSQL 791 | library directory and that `oracle_fdw.control` and the SQL files are in 792 | the PostgreSQL extension directory. 793 | 794 | Since the Oracle client shared library is probably not in the standard 795 | library path, you have to make sure that the PostgreSQL server will be able 796 | to find it. How this is done varies from operating system to operating 797 | system; on Linux you can set LD_LIBRARY_PATH or use `/etc/ld.so.conf`. 798 | 799 | Make sure that all necessary Oracle environment variables are set in the 800 | environment of the PostgreSQL server process (ORACLE_HOME if you don't use 801 | Instant Client, TNS_ADMIN if you have configuration files, etc.) 802 | 803 | To install the extension in a database, connect as superuser and 804 | 805 | CREATE EXTENSION oracle_fdw; 806 | 807 | That will define the required functions and create a foreign data wrapper. 808 | 809 | To upgrade from an oracle_fdw version before 2.3.0, use 810 | 811 | ALTER EXTENSION oracle_fdw UPDATE; 812 | 813 | Note that the extension version as shown by the psql command `\dx` or the 814 | system catalog `pg_available_extensions` is *not* the installed version 815 | of oracle_fdw. To get the oracle_fdw version, use the function `oracle_diag`. 816 | 817 | Running the regression tests: 818 | ----------------------------- 819 | 820 | Unless you are developing oracle_fdw or want to test its functionality 821 | on an exotic platform, you don't have to do this. 822 | 823 | For the regression tests to work, you must have a PostgreSQL cluster 824 | and an Oracle server (10.2 or better with Locator or Spatial) running, 825 | and the oracle_fdw binaries must be installed. 826 | The regression tests will create a database called `contrib_regression` and 827 | run a number of tests. For the PostGIS regression tests to succeed, 828 | the PostGIS binaries must be installed. 829 | 830 | The Oracle database must be prepared as follows: 831 | - A user `scott` with password `tiger` must exist (unless you want to edit 832 | the regression test scripts). The user needs CREATE SESSION, CREATE TABLE, 833 | CREATE VIEW and CREATE MATERIALIZED VIEW system privileges and enough quota 834 | on its default tablespace, as well as SELECT privileges on V$SQL and 835 | V$SQL_PLAN. 836 | 837 | Set the environment for the PostgreSQL server so that it can establish an 838 | Oracle connection without connect string: 839 | If the Oracle server is on the same machine, set the environment variables 840 | ORACLE_SID and ORACLE_HOME appropriately, for a remote server set the 841 | environment variable TWO_TASK (or LOCAL on Windows) to the connect string. 842 | 843 | The regression tests are run as follows: 844 | 845 | $ make installcheck 846 | 847 | The regression tests are kept up to date with the latest development version of 848 | PostgreSQL. If you run them with older PostgreSQL versions, you can expect 849 | minor differences, like changed error messages or a different format of the 850 | psql output. 851 | 852 | 7 Internals 853 | =========== 854 | 855 | oracle_fdw sets the MODULE of the Oracle session to `postgres` and the 856 | ACTION to the backend process number. This can help identifying the Oracle 857 | session and allows you to trace it with DBMS_MONITOR.SERV_MOD_ACT_TRACE_ENABLE. 858 | 859 | oracle_fdw uses Oracle's array interface to avoid unnecessary client-server 860 | round-trips. The batch size can be configured with the **prefetch** table 861 | option and is set to 50 by default. 862 | 863 | Rather than using a PLAN_TABLE to explain an Oracle query (which would require 864 | such a table to be created in the Oracle database), oracle_fdw uses execution 865 | plans stored in the library cache. For that, an Oracle query is *explicitly 866 | described*, which forces Oracle to parse the query. The hard part is to find 867 | the SQL_ID and CHILD_NUMBER of the statement in V$SQL because the SQL_TEXT 868 | column contains only the first 1000 bytes of the query. 869 | Therefore, oracle_fdw adds a comment to the query that contains a hash 870 | of the query text. This is used to search in V$SQL. 871 | The actual execution plan or cost information is retrieved from V$SQL_PLAN. 872 | 873 | oracle_fdw uses transaction isolation level SERIALIZABLE on the Oracle side, 874 | which corresponds to PostgreSQL's REPEATABLE READ. This is necessary because 875 | a single PostgreSQL statement can lead to multiple Oracle queries (e.g. during 876 | a nested loop join) and the results need to be consistent. 877 | Unfortunately the Oracle implementation of SERIALIZABLE has certain quirks; 878 | see the [Problems](#8-problems) section for more. 879 | 880 | The Oracle transaction is committed immediately before the local transaction 881 | commits, so that a completed PostgreSQL transaction guarantees that the Oracle 882 | transaction has completed. However, there is a small chance that the 883 | PostgreSQL transaction cannot complete even though the Oracle transaction 884 | is committed. This cannot be avoided without using two-phase transactions 885 | and a transaction manager, which is beyond what a foreign data wrapper 886 | can reasonably provide. 887 | Prepared statements involving Oracle are not supported for the same reason. 888 | 889 | 8 Problems 890 | ========== 891 | 892 | Encoding 893 | -------- 894 | 895 | Characters stored in an Oracle database that cannot be converted to the 896 | PostgreSQL database encoding will silently be replaced by *replacement 897 | characters*, typically a normal or inverted question mark, by Oracle. 898 | You will get no warning or error messages. 899 | 900 | If you use a PostgreSQL database encoding that Oracle does not know 901 | (currently, these are EUC_CN, EUC_KR, LATIN10, MULE_INTERNAL, 902 | WIN874 and SQL_ASCII), non-ASCII characters cannot be translated 903 | correctly. You will get a warning in this case, and the characters 904 | will be replaced by replacement characters as described above. 905 | 906 | You can set the **nls_lang** option of the foreign data wrapper to force a 907 | certain Oracle encoding, but the resulting characters will most likely be 908 | incorrect and lead to PostgreSQL error messages. This is probably only 909 | useful for SQL_ASCII encoding if you know what you are doing. 910 | See the [Options](#3-options) section. 911 | 912 | Limited functionality in old Oracle versions 913 | -------------------------------------------- 914 | 915 | - The definition of the Oracle system catalogs V$SQL and V$SQL_PLAN has 916 | changed with Oracle 10.1. Using EXPLAIN VERBOSE with older Oracle server 917 | versions will result in errors like: 918 | 919 | ERROR: error describing query: OCIStmtExecute failed to execute 920 | remote query for sql_id 921 | DETAIL: ORA-00904: "LAST_ACTIVE_TIME": invalid identifier 922 | 923 | There is no plan to fix this, since Oracle 9i has been out of Extended Support 924 | since 2010 and the functionality is not essential. 925 | 926 | - IMPORT FOREIGN SCHEMA throws the following error with Oracle server 8i: 927 | 928 | ERROR: error importing foreign schema: OCIStmtExecute failed to execute 929 | column query 930 | DETAIL: ORA-00904: invalid column name 931 | 932 | This is because the view ALL_TAB_COLUMNS lacks the column CHAR_LENGTH, 933 | which was added in Oracle 9i. 934 | 935 | LDAP libraries 936 | -------------- 937 | 938 | The Oracle client shared library comes with its own LDAP client 939 | implementation conforming to [RFC 1823](http://www.rfc-base.org/rfc-1823.html), 940 | so these functions have the same names as OpenLDAP's. This will lead to a 941 | name collision when the PostgreSQL server was configured `--with-ldap`. 942 | 943 | The name collision will not be detected, because oracle_fdw is loaded at 944 | runtime, but trouble will happen if anybody calls an LDAP function. 945 | Typically, OpenLDAP is loaded first, so if Oracle calls an LDAP function 946 | (for example if you use *directory naming* name resolution), the backend 947 | will crash. This can lead to messages like the following (seen on Linux) 948 | in the PostgreSQL server log: 949 | 950 | ../../../libraries/libldap/getentry.c:29: ldap_first_entry: 951 | Assertion `( (ld)->ld_options.ldo_valid == 0x2 )' failed. 952 | 953 | The best thing is to configure PostgreSQL `--without-ldap`. This is the only 954 | safe way to avoid this problem. 955 | Even when PostgreSQL is built `--with-ldap`, it may work as long as you don't 956 | use any LDAP client functionality in Oracle. 957 | On some platforms, you can force Oracle's client shared library to be loaded 958 | before the PostgreSQL server is started (LD_PRELOAD on Linux). Then Oracle's 959 | LDAP functions should get used. In that case, Oracle may be able to use 960 | LDAP functionality, but using LDAP from PostgreSQL will crash the backend. 961 | 962 | You cannot use LDAP functionality both in PostgreSQL and in Oracle, period. 963 | 964 | Serialization errors 965 | -------------------- 966 | 967 | In Oracle 11.2 or above, inserting the first row into a newly created 968 | Oracle table with oracle_fdw will lead to a serialization error. 969 | 970 | This is because of an Oracle feature called *deferred segment creation* which 971 | defers allocation of storage space for a new table until the first row 972 | is inserted. This causes a serialization failure with serializable 973 | transactions (see document 1285464.1 in Oracle's knowledge base). 974 | 975 | This is no serious problem; you can work around it by either ignoring that 976 | first error or creating the table with SEGMENT CREATION IMMEDIATE. 977 | 978 | A much nastier problem is that concurrent inserts can sometimes cause 979 | serialization errors when an index page is split concurrently with a 980 | modifying serializable transaction (see Oracle document 160593.1). 981 | 982 | Oracle claims that this is not a bug, and the suggested solution is to retry 983 | the transaction that got a serialization error. 984 | 985 | Oracle bugs 986 | ----------- 987 | 988 | This is a list of Oracle bugs that affect or have affected oracle_fdw. 989 | 990 | Bug 2728408 can cause `ORA-8177 cannot serialize access for this transaction` 991 | even if no modification of remote data is attempted. 992 | It can occur with Oracle server 8.1.7.4 (install one-off patch 2728408) or 993 | Oracle server 9.2 (install Patch Set 9.2.0.4 or better). 994 | 995 | Oracle client 21c is known not to work for CLOB columns (they appear empty). 996 | There is no ultimate proof that that is an Oracle bug, but other versions 997 | are working fine. 998 | 999 | Missing Oracle client DLL (on Windows only) 1000 | ------------------------------------------- 1001 | 1002 | The following error message (from any query involving an Oracle foreign 1003 | table) indicates that PostgreSQL cannot find the Oracle client library: 1004 | 1005 | ERROR: Oracle client library (oci.dll) not found 1006 | DETAIL: No Oracle client is installed, or your system is configured incorrectly. 1007 | HINT: Verify that the PATH variable includes the Oracle client. 1008 | 1009 | Make sure that the path to `oci.dll` is in the PATH environment variable of 1010 | the user running the PostgreSQL server. If it is running as a Windows service, 1011 | this is the system environment, and you must restart the service after 1012 | changing it. 1013 | 1014 | If updating the environment does not work, you may be using a PostgreSQL 1015 | distribution that provides its own environment variables, hiding the Oracle 1016 | client. See the bug report at https://github.com/laurenz/oracle_fdw/issues/160 1017 | for more information. 1018 | 1019 | 9 Support 1020 | ========= 1021 | 1022 | Check out the [Wiki](https://github.com/laurenz/oracle_fdw/wiki) for 1023 | help with configuration on certain platforms and other problems. 1024 | Also, searching the 1025 | [GitHub issues](https://github.com/laurenz/oracle_fdw/issues) 1026 | can help - you may not be the first one with that problem. 1027 | 1028 | If you want to report a problem with oracle_fdw, and the name of the 1029 | foreign server is (for example) "ora_serv", please include the output of 1030 | 1031 | SELECT oracle_diag('ora_serv'); 1032 | 1033 | in your problem report. 1034 | If that causes an error, please also include the output of 1035 | 1036 | SELECT oracle_diag(); 1037 | 1038 | If you have a problem or question or any kind of feedback, the preferred 1039 | option is to open an issue on GitHub: 1040 | https://github.com/laurenz/oracle_fdw/issues 1041 | This requires a GitHub account. 1042 | 1043 | Commercial support is available from 1044 | [CYBERTEC PostgreSQL International GmbH][https://www.cybertec-postgresql.com]. 1045 | -------------------------------------------------------------------------------- /TODO: -------------------------------------------------------------------------------- 1 | This is a list of things that would be nice to have. 2 | Help is welcome! 3 | 4 | - Set parameters like NLS_DATE_FORMAT *after* the Oracle connection has been 5 | established. Otherwise, an ill-guided Oracle logon trigger could mess up 6 | our NLS settings. 7 | This should not be too hard, but nobody has got around to do it so far. 8 | 9 | The following features would be nice to have, but prior attempts to add them 10 | have failed, which was not necessarily the fault of the contributors. 11 | 12 | - Add a sample Docker file to build a container with PostgreSQL and oracle_fdw. 13 | This can also serve as a cookbook for installing the software. 14 | The main problem here is that we'd need a maintainer who knows about Docker. 15 | See https://github.com/laurenz/oracle_fdw/pull/644 16 | 17 | - Aggregate pushdown. 18 | This is a big feature, and the main challenge is to write a patch that can 19 | be understood and reviewed by the maintainers. 20 | See https://github.com/laurenz/oracle_fdw/issues/569 21 | -------------------------------------------------------------------------------- /expected/oracle_gis.out: -------------------------------------------------------------------------------- 1 | /* 2 | * Define the PostGIS extension and create a foreign table. 3 | */ 4 | CREATE EXTENSION postgis; 5 | -- reconnect so that oracle_fdw recognizes PostGIS 6 | \c 7 | SET client_min_messages = WARNING; 8 | -- Table with a PostGIS geometry 9 | CREATE FOREIGN TABLE gis ( 10 | id integer OPTIONS (key 'on') NOT NULL, 11 | g geometry 12 | ) SERVER oracle OPTIONS (table 'GIS'); 13 | /* 14 | * Empty the table and INSERT some data. 15 | */ 16 | -- empty table 17 | DELETE FROM gis; 18 | -- INSERT a couple of rows 19 | INSERT INTO gis (id, g) VALUES 20 | (1, 'SRID=8307;POINT(16.4891 48.1754)'), 21 | (2, 'SRID=0;LINESTRING(1552410.48 6720732.7,1552408.69 6720731.97)'), 22 | (3, 'SRID=8307;POINT Z (1.5 2.6 3.7)'), 23 | (4, NULL), 24 | (5, 'SRID=8307;MULTIPOLYGON(((50 168,50 160,55 160,55 168,50 168),(51 167,54 167,54 161,51 161,51 162,52 163,51 164,51 165,51 166,51 167)),((52 166,52 162,53 162,53 166,52 166)))'), 25 | (6, 'SRID=8307;POLYGON((35 10,45 45,15 40,10 20,35 10),(20 30,35 35,30 20,20 30))'), 26 | (7, 'SRID=8307;MULTILINESTRING((10 10,20 20,10 40),(40 40,30 30,40 20,30 10))'), 27 | (8, 'SRID=8307;MULTIPOLYGON(((40 40,20 45,45 30,40 40)),((20 35,10 30,10 10,30 5,45 20,20 35),(30 20,20 15,20 25,30 20)))'), 28 | (9, 'SRID=8307;POINT M (12 13 14)'), 29 | (10, 'SRID=8307;POLYGON M ((0 0 0, 1 0 2, 1 1 4, 0 1 2, 0 0 0))'); 30 | /* 31 | * Test empty geometries. 32 | */ 33 | UPDATE gis SET g = 'POINT Z EMPTY' WHERE id = 1; 34 | ERROR: error converting geometry to SDO_GEOMETRY: empty point is not supported 35 | UPDATE gis SET g = 'MULTIPOLYGON(((10 10,20 10,20 20,10 20,10 10)),EMPTY)' WHERE id = 8; 36 | ERROR: error converting geometry to SDO_GEOMETRY: empty polygon is not supported 37 | /* 38 | * Test four-dimensional geometry. 39 | */ 40 | UPDATE gis SET g = 'POINT ZM (12 13 14 15)'; 41 | ERROR: error converting geometry to SDO_GEOMETRY: measure dimension only supported for two-dimensional geometries 42 | /* 43 | * Test SELECT and UPDATE ... RETURNING. 44 | */ 45 | -- simple SELECT 46 | SELECT id, st_srid(g), st_astext(g) FROM gis ORDER BY id; 47 | id | st_srid | st_astext 48 | ----+---------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------- 49 | 1 | 8307 | POINT(16.4891 48.1754) 50 | 2 | 0 | LINESTRING(1552410.48 6720732.7,1552408.69 6720731.97) 51 | 3 | 8307 | POINT Z (1.5 2.6 3.7) 52 | 4 | | 53 | 5 | 8307 | MULTIPOLYGON(((50 168,50 160,55 160,55 168,50 168),(51 167,54 167,54 161,51 161,51 162,52 163,51 164,51 165,51 166,51 167)),((52 166,52 162,53 162,53 166,52 166))) 54 | 6 | 8307 | POLYGON((35 10,45 45,15 40,10 20,35 10),(20 30,35 35,30 20,20 30)) 55 | 7 | 8307 | MULTILINESTRING((10 10,20 20,10 40),(40 40,30 30,40 20,30 10)) 56 | 8 | 8307 | MULTIPOLYGON(((40 40,20 45,45 30,40 40)),((20 35,10 30,10 10,30 5,45 20,20 35),(30 20,20 15,20 25,30 20))) 57 | 9 | 8307 | POINT M (12 13 14) 58 | 10 | 8307 | POLYGON M ((0 0 0,1 0 2,1 1 4,0 1 2,0 0 0)) 59 | (10 rows) 60 | 61 | -- UPDATE with RETURNING clause 62 | WITH upd (id, srid, wkt) AS 63 | (UPDATE gis SET g=g RETURNING id, st_srid(g), st_astext(g)) 64 | SELECT * FROM upd ORDER BY id; 65 | id | srid | wkt 66 | ----+------+--------------------------------------------------------------------------------------------------------------------------------------------------------------------- 67 | 1 | 8307 | POINT(16.4891 48.1754) 68 | 2 | 0 | LINESTRING(1552410.48 6720732.7,1552408.69 6720731.97) 69 | 3 | 8307 | POINT Z (1.5 2.6 3.7) 70 | 4 | | 71 | 5 | 8307 | MULTIPOLYGON(((50 168,50 160,55 160,55 168,50 168),(51 167,54 167,54 161,51 161,51 162,52 163,51 164,51 165,51 166,51 167)),((52 166,52 162,53 162,53 166,52 166))) 72 | 6 | 8307 | POLYGON((35 10,45 45,15 40,10 20,35 10),(20 30,35 35,30 20,20 30)) 73 | 7 | 8307 | MULTILINESTRING((10 10,20 20,10 40),(40 40,30 30,40 20,30 10)) 74 | 8 | 8307 | MULTIPOLYGON(((40 40,20 45,45 30,40 40)),((20 35,10 30,10 10,30 5,45 20,20 35),(30 20,20 15,20 25,30 20))) 75 | 9 | 8307 | POINT M (12 13 14) 76 | 10 | 8307 | POLYGON M ((0 0 0,1 0 2,1 1 4,0 1 2,0 0 0)) 77 | (10 rows) 78 | 79 | -------------------------------------------------------------------------------- /expected/oracle_import.out: -------------------------------------------------------------------------------- 1 | SET client_min_messages = WARNING; 2 | CREATE SCHEMA import; 3 | /* first, import only a table and a materialized view */ 4 | IMPORT FOREIGN SCHEMA "SCOTT" 5 | LIMIT TO ("typetest1", ttv, mattest2) 6 | FROM SERVER oracle 7 | INTO import 8 | OPTIONS (case 'lower', collation 'C', skip_views 'true'); 9 | SELECT t.relname, fs.srvname, ft.ftoptions 10 | FROM pg_foreign_table ft 11 | JOIN pg_class t ON ft.ftrelid = t.oid 12 | JOIN pg_foreign_server fs ON ft.ftserver = fs.oid 13 | WHERE relnamespace = 'import'::regnamespace 14 | ORDER BY t.relname; 15 | relname | srvname | ftoptions 16 | -----------+---------+-------------------------------- 17 | mattest2 | oracle | {schema=SCOTT,table=MATTEST2} 18 | typetest1 | oracle | {schema=SCOTT,table=TYPETEST1} 19 | (2 rows) 20 | 21 | /* then import only a view */ 22 | IMPORT FOREIGN SCHEMA "SCOTT" 23 | LIMIT TO ("typetest1", ttv, mattest2) 24 | FROM SERVER oracle 25 | INTO import 26 | OPTIONS (case 'lower', skip_tables 'true', skip_matviews 'true'); 27 | SELECT t.relname, fs.srvname, ft.ftoptions 28 | FROM pg_foreign_table ft 29 | JOIN pg_class t ON ft.ftrelid = t.oid 30 | JOIN pg_foreign_server fs ON ft.ftserver = fs.oid 31 | WHERE relnamespace = 'import'::regnamespace 32 | ORDER BY t.relname; 33 | relname | srvname | ftoptions 34 | -----------+---------+-------------------------------- 35 | mattest2 | oracle | {schema=SCOTT,table=MATTEST2} 36 | ttv | oracle | {schema=SCOTT,table=TTV} 37 | typetest1 | oracle | {schema=SCOTT,table=TYPETEST1} 38 | (3 rows) 39 | 40 | SELECT t.relname, a.attname, a.atttypid::regtype, a.attfdwoptions 41 | FROM pg_attribute AS a 42 | JOIN pg_class AS t ON t.oid = a.attrelid 43 | WHERE t.relname IN ('typetest1', 'ttv', 'mattest2') 44 | AND a.attnum > 0 45 | AND t.relnamespace = 'import'::regnamespace 46 | AND NOT a.attisdropped 47 | ORDER BY t.relname, a.attnum; 48 | relname | attname | atttypid | attfdwoptions 49 | -----------+---------+-----------------------------+--------------- 50 | mattest2 | id | integer | {key=true} 51 | mattest2 | ts1 | timestamp with time zone | 52 | mattest2 | ts2 | timestamp with time zone | 53 | mattest2 | ts3 | timestamp with time zone | 54 | ttv | id | integer | 55 | ttv | vc | character varying | 56 | typetest1 | id | integer | {key=true} 57 | typetest1 | c | character | 58 | typetest1 | nc | character | 59 | typetest1 | vc | character varying | 60 | typetest1 | nvc | character varying | 61 | typetest1 | lc | text | 62 | typetest1 | lnc | text | 63 | typetest1 | r | bytea | 64 | typetest1 | u | bytea | 65 | typetest1 | lb | bytea | 66 | typetest1 | lr | bytea | 67 | typetest1 | b | smallint | 68 | typetest1 | num | numeric | 69 | typetest1 | fl | real | 70 | typetest1 | db | double precision | 71 | typetest1 | d | timestamp without time zone | 72 | typetest1 | ts | timestamp with time zone | 73 | typetest1 | ids | interval | 74 | typetest1 | iym | interval | 75 | (25 rows) 76 | 77 | -------------------------------------------------------------------------------- /msvc/oracle_fdw.props: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | 5 | 6 | C:\Daten\work\install\oracle64\instantclient_10_2 7 | C:\Daten\pgsql\pg10-x64 8 | 9 | 10 | C:\Daten\work\install\oracle32\instantclient_10_2 11 | C:\Daten\pgsql\pg10-x86 12 | 13 | 14 | $(PostgreSQL)\include\server\port\win32_msvc;$(PostgreSQL)\include\server\port\win32;$(PostgreSQL)\include\server\port;$(PostgreSQL)\include\server;$(PostgreSQL)\include\internal;$(PostgreSQL)\include;$(OracleClient)\sdk\include;$(IncludePath) 15 | $(PostgreSQL)\lib;$(OracleClient)\sdk\lib\msvc;$(LibraryPath) 16 | 17 | 18 | 19 | -------------------------------------------------------------------------------- /msvc/oracle_fdw.sln: -------------------------------------------------------------------------------- 1 |  2 | Microsoft Visual Studio Solution File, Format Version 12.00 3 | # Visual Studio 2013 4 | VisualStudioVersion = 12.0.40629.0 5 | MinimumVisualStudioVersion = 10.0.40219.1 6 | Project("{8BC9CEB8-8B4A-11D0-8D11-00A0C91BC942}") = "oracle_fdw", "oracle_fdw.vcxproj", "{E4E300FC-E7CE-4BAA-9028-AA348F977376}" 7 | EndProject 8 | Global 9 | GlobalSection(SolutionConfigurationPlatforms) = preSolution 10 | Debug|Win32 = Debug|Win32 11 | Debug|x64 = Debug|x64 12 | Release|Win32 = Release|Win32 13 | Release|x64 = Release|x64 14 | EndGlobalSection 15 | GlobalSection(ProjectConfigurationPlatforms) = postSolution 16 | {E4E300FC-E7CE-4BAA-9028-AA348F977376}.Debug|Win32.ActiveCfg = Debug|Win32 17 | {E4E300FC-E7CE-4BAA-9028-AA348F977376}.Debug|Win32.Build.0 = Debug|Win32 18 | {E4E300FC-E7CE-4BAA-9028-AA348F977376}.Debug|x64.ActiveCfg = Debug|x64 19 | {E4E300FC-E7CE-4BAA-9028-AA348F977376}.Debug|x64.Build.0 = Debug|x64 20 | {E4E300FC-E7CE-4BAA-9028-AA348F977376}.Release|Win32.ActiveCfg = Release|Win32 21 | {E4E300FC-E7CE-4BAA-9028-AA348F977376}.Release|Win32.Build.0 = Release|Win32 22 | {E4E300FC-E7CE-4BAA-9028-AA348F977376}.Release|x64.ActiveCfg = Release|x64 23 | {E4E300FC-E7CE-4BAA-9028-AA348F977376}.Release|x64.Build.0 = Release|x64 24 | EndGlobalSection 25 | GlobalSection(SolutionProperties) = preSolution 26 | HideSolutionNode = FALSE 27 | EndGlobalSection 28 | EndGlobal 29 | -------------------------------------------------------------------------------- /msvc/oracle_fdw.vcxproj: -------------------------------------------------------------------------------- 1 |  2 | 3 | 4 | Release 5 | 6 | 7 | 8 | Debug 9 | Win32 10 | 11 | 12 | Debug 13 | x64 14 | 15 | 16 | Release 17 | Win32 18 | 19 | 20 | Release 21 | x64 22 | 23 | 24 | 25 | {E4E300FC-E7CE-4BAA-9028-AA348F977376} 26 | oracle_fdw 27 | 28 | 29 | 30 | DynamicLibrary 31 | true 32 | $(DefaultPlatformToolset) 33 | MultiByte 34 | 35 | 36 | DynamicLibrary 37 | true 38 | $(DefaultPlatformToolset) 39 | MultiByte 40 | 41 | 42 | DynamicLibrary 43 | false 44 | $(DefaultPlatformToolset) 45 | true 46 | MultiByte 47 | 48 | 49 | DynamicLibrary 50 | false 51 | $(DefaultPlatformToolset) 52 | true 53 | MultiByte 54 | 55 | 56 | 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | 74 | 75 | 76 | $(SolutionDir)$(Platform)\$(Configuration)\ 77 | $(SolutionDir)$(Platform)\$(Configuration)\ 78 | 79 | 80 | $(SolutionDir)$(Platform)\$(Configuration)\ 81 | $(SolutionDir)$(Platform)\$(Configuration)\ 82 | 83 | 84 | $(SolutionDir)$(Platform)\$(Configuration)\ 85 | $(SolutionDir)$(Platform)\$(Configuration)\ 86 | 87 | 88 | $(SolutionDir)$(Platform)\$(Configuration)\ 89 | $(SolutionDir)$(Platform)\$(Configuration)\ 90 | 91 | 92 | 93 | Level4 94 | Disabled 95 | true 96 | false 97 | false 98 | _CRT_SECURE_NO_WARNINGS;%(PreprocessorDefinitions) 99 | 4200;4244;4267;4389;4018;4996;4100;4127 100 | Async 101 | 102 | 103 | true 104 | postgres.lib;oci.lib;delayimp.lib;%(AdditionalDependencies) 105 | oci.dll 106 | 107 | 108 | 109 | 110 | Level4 111 | Disabled 112 | true 113 | false 114 | false 115 | _CRT_SECURE_NO_WARNINGS;%(PreprocessorDefinitions) 116 | 4200;4244;4267;4389;4018;4996;4100;4127 117 | Async 118 | 119 | 120 | true 121 | postgres.lib;oci.lib;delayimp.lib;%(AdditionalDependencies) 122 | oci.dll 123 | 124 | 125 | 126 | 127 | Level4 128 | Full 129 | true 130 | true 131 | true 132 | true 133 | _CRT_SECURE_NO_WARNINGS;%(PreprocessorDefinitions) 134 | 4200;4244;4267;4389;4018;4996;4100;4127 135 | Async 136 | 137 | 138 | true 139 | true 140 | true 141 | postgres.lib;oci.lib;delayimp.lib;%(AdditionalDependencies) 142 | oci.dll 143 | 144 | 145 | 146 | 147 | Level4 148 | Full 149 | true 150 | true 151 | true 152 | true 153 | _CRT_SECURE_NO_WARNINGS;%(PreprocessorDefinitions) 154 | 4200;4244;4267;4389;4018;4996;4100;4127 155 | Async 156 | 157 | 158 | true 159 | true 160 | true 161 | postgres.lib;oci.lib;delayimp.lib;%(AdditionalDependencies) 162 | oci.dll 163 | 164 | 165 | 166 | 167 | 168 | 169 | 170 | 171 | 172 | 173 | 174 | 175 | 176 | 177 | 178 | -------------------------------------------------------------------------------- /msvc/oracle_msvc.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | #include "utils\elog.h" 3 | 4 | #include "..\oracle_fdw.h" 5 | 6 | #include 7 | 8 | #pragma warning(push) 9 | #pragma warning(disable: 4201) 10 | #include 11 | #pragma warning(pop) 12 | 13 | #define ERRMSG_LIB "Oracle client library (oci.dll) not found" 14 | #define ERRDETAIL_LIB "No Oracle client is installed, or your system is configured incorrectly." 15 | #define ERRMSG_PROC "Incompatible version of Oracle client library (oci.dll) found" 16 | #define ERRDETAIL_PROC "An exported function was not found in oci.dll." 17 | 18 | FARPROC WINAPI 19 | oracleDelayLoadFailureHook(unsigned dliNotify, PDelayLoadInfo pdli) 20 | { 21 | if (dliNotify == dliFailLoadLib) { 22 | #if defined(ORAFDW_INSECURE_DIAG) 23 | ereport(ERROR, 24 | (errcode(ERRCODE_SYSTEM_ERROR), 25 | errmsg(ERRMSG_LIB), 26 | errdetail(ERRDETAIL_LIB), 27 | errhint("The current PATH is: %s", getenv("PATH")))); 28 | #else 29 | ereport(ERROR, 30 | (errcode(ERRCODE_SYSTEM_ERROR), 31 | errmsg(ERRMSG_LIB), 32 | errdetail(ERRDETAIL_LIB), 33 | errhint("Verify that the PATH variable includes the Oracle client."))); 34 | #endif /* ORAFDW_INSECURE_DIAG */ 35 | } 36 | else if (dliNotify == dliFailGetProc) { 37 | /* There are no exports by ordinal yets. */ 38 | if (pdli->dlp.fImportByName) { 39 | ereport(ERROR, 40 | (errcode(ERRCODE_SYSTEM_ERROR), 41 | errmsg(ERRMSG_PROC), 42 | errdetail(ERRDETAIL_PROC), 43 | errhint("Missing function: %s", pdli->dlp.szProcName))); 44 | } 45 | else { 46 | ereport(ERROR, 47 | (errcode(ERRCODE_SYSTEM_ERROR), 48 | errmsg(ERRMSG_PROC), 49 | errdetail(ERRDETAIL_PROC), 50 | errhint("Missing ordinal: #%u", pdli->dlp.dwOrdinal))); 51 | } 52 | } 53 | return 0; 54 | } 55 | 56 | ExternC 57 | #if _MSC_FULL_VER >= 190024210 /* VS 2015 Update 3 */ 58 | const 59 | #endif 60 | PfnDliHook __pfnDliFailureHook2 = oracleDelayLoadFailureHook; 61 | -------------------------------------------------------------------------------- /oracle_fdw--1.0--1.1.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION oracle_diag(name DEFAULT NULL) RETURNS text 2 | AS 'MODULE_PATHNAME' 3 | LANGUAGE C STABLE CALLED ON NULL INPUT; 4 | 5 | COMMENT ON FUNCTION oracle_diag(name) 6 | IS 'shows the version of oracle_fdw, Oracle client and Oracle server'; 7 | -------------------------------------------------------------------------------- /oracle_fdw--1.1--1.2.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION oracle_execute(server name, statement text) RETURNS void 2 | AS 'MODULE_PATHNAME' 3 | LANGUAGE C STRICT; 4 | 5 | COMMENT ON FUNCTION oracle_execute(name, text) 6 | IS 'executes an arbitrary SQL statement with no results on the Oracle server'; 7 | -------------------------------------------------------------------------------- /oracle_fdw--1.2.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION oracle_fdw_handler() RETURNS fdw_handler 2 | AS 'MODULE_PATHNAME' 3 | LANGUAGE C STRICT; 4 | 5 | COMMENT ON FUNCTION oracle_fdw_handler() 6 | IS 'Oracle foreign data wrapper handler'; 7 | 8 | CREATE FUNCTION oracle_fdw_validator(text[], oid) RETURNS void 9 | AS 'MODULE_PATHNAME' 10 | LANGUAGE C STRICT; 11 | 12 | COMMENT ON FUNCTION oracle_fdw_validator(text[], oid) 13 | IS 'Oracle foreign data wrapper options validator'; 14 | 15 | CREATE FUNCTION oracle_close_connections() RETURNS void 16 | AS 'MODULE_PATHNAME' 17 | LANGUAGE C STRICT; 18 | 19 | COMMENT ON FUNCTION oracle_close_connections() 20 | IS 'closes all open Oracle connections'; 21 | 22 | CREATE FUNCTION oracle_diag(name DEFAULT NULL) RETURNS text 23 | AS 'MODULE_PATHNAME' 24 | LANGUAGE C STABLE CALLED ON NULL INPUT; 25 | 26 | COMMENT ON FUNCTION oracle_diag(name) 27 | IS 'shows the version of oracle_fdw, PostgreSQL, Oracle client and Oracle server'; 28 | 29 | CREATE FUNCTION oracle_execute(server name, statement text) RETURNS void 30 | AS 'MODULE_PATHNAME' 31 | LANGUAGE C STRICT; 32 | 33 | COMMENT ON FUNCTION oracle_execute(name, text) 34 | IS 'executes an arbitrary SQL statement with no results on the Oracle server'; 35 | 36 | CREATE FOREIGN DATA WRAPPER oracle_fdw 37 | HANDLER oracle_fdw_handler 38 | VALIDATOR oracle_fdw_validator; 39 | 40 | COMMENT ON FOREIGN DATA WRAPPER oracle_fdw 41 | IS 'Oracle foreign data wrapper'; 42 | -------------------------------------------------------------------------------- /oracle_fdw.control: -------------------------------------------------------------------------------- 1 | comment = 'foreign data wrapper for Oracle access' 2 | default_version = '1.2' 3 | module_pathname = '$libdir/oracle_fdw' 4 | relocatable = true 5 | -------------------------------------------------------------------------------- /oracle_fdw.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * oracle_fdw.h 4 | * This header file contains all definitions that are shared by 5 | * oracle_fdw.c and oracle_utils.c. 6 | * It is necessary to split oracle_fdw into two source files because 7 | * PostgreSQL and Oracle headers cannot be #included at the same time. 8 | * 9 | *------------------------------------------------------------------------- 10 | */ 11 | 12 | /* this one is safe to include and gives us Oid */ 13 | #include "postgres_ext.h" 14 | 15 | #include 16 | #include 17 | 18 | /* oracle_fdw version */ 19 | #define ORACLE_FDW_VERSION "2.8.1devel" 20 | 21 | /* definitions that need OCI */ 22 | #ifdef OCI_ORACLE 23 | /* 24 | * Types for a linked list for various handles. 25 | * Oracle sessions can be multiplexed over one server connection. 26 | */ 27 | struct connEntry 28 | { 29 | char *user; 30 | OCISvcCtx *svchp; 31 | OCISession *userhp; 32 | OCIType *geomtype; 33 | struct stmtHandleEntry *stmtlist; 34 | int xact_level; /* 0 = none, 1 = main, else subtransaction */ 35 | struct connEntry *next; 36 | }; 37 | 38 | struct srvEntry 39 | { 40 | char *connectstring; 41 | OCIServer *srvhp; 42 | struct srvEntry *next; 43 | struct connEntry *connlist; 44 | int server_version[5]; 45 | }; 46 | 47 | struct envEntry 48 | { 49 | char *nls_lang; 50 | char *timezone; 51 | OCIEnv *envhp; 52 | OCIError *errhp; 53 | struct envEntry *next; 54 | struct srvEntry *srvlist; 55 | }; 56 | 57 | /* 58 | * Represents one Oracle connection, points to cached entries. 59 | * This is necessary to be able to pass them back to 60 | * oracle_fdw.c without having to #include oci.h there. 61 | */ 62 | struct oracleSession 63 | { 64 | struct envEntry *envp; 65 | struct srvEntry *srvp; 66 | struct connEntry *connp; 67 | OCIStmt *stmthp; 68 | int have_nchar; 69 | int server_version[5]; 70 | unsigned int last_batch; /* got OCI_NO_DATA */ 71 | unsigned int fetched_rows; 72 | unsigned int current_row; /* first row is 1 */ 73 | }; 74 | #endif 75 | typedef struct oracleSession oracleSession; 76 | 77 | /* types for the Oracle table description */ 78 | typedef enum 79 | { 80 | ORA_TYPE_VARCHAR2, 81 | ORA_TYPE_CHAR, 82 | ORA_TYPE_NVARCHAR2, 83 | ORA_TYPE_NCHAR, 84 | ORA_TYPE_NUMBER, 85 | ORA_TYPE_FLOAT, 86 | ORA_TYPE_BINARYFLOAT, 87 | ORA_TYPE_BINARYDOUBLE, 88 | ORA_TYPE_RAW, 89 | ORA_TYPE_DATE, 90 | ORA_TYPE_TIMESTAMP, 91 | ORA_TYPE_TIMESTAMPTZ, 92 | ORA_TYPE_TIMESTAMPLTZ, /* TIMESTAMP WITH LOCAL TIME ZONE */ 93 | ORA_TYPE_INTERVALY2M, 94 | ORA_TYPE_INTERVALD2S, 95 | ORA_TYPE_BLOB, 96 | ORA_TYPE_CLOB, 97 | ORA_TYPE_NCLOB, 98 | ORA_TYPE_BFILE, 99 | ORA_TYPE_LONG, 100 | ORA_TYPE_LONGRAW, 101 | ORA_TYPE_GEOMETRY, 102 | ORA_TYPE_XMLTYPE, 103 | ORA_TYPE_OTHER 104 | } oraType; 105 | 106 | /* Some PostgreSQL versions have no constant definition for the OID of type uuid */ 107 | #ifndef UUIDOID 108 | #define UUIDOID 2950 109 | #endif 110 | 111 | /* PostgreSQL before 9.6 doesn't have this macro */ 112 | #ifndef ALLOCSET_SMALL_SIZES 113 | #define ALLOCSET_SMALL_SIZES \ 114 | ALLOCSET_SMALL_MINSIZE, ALLOCSET_SMALL_INITSIZE, ALLOCSET_SMALL_MAXSIZE 115 | #endif 116 | 117 | struct oraColumn 118 | { 119 | char *name; /* name in Oracle */ 120 | oraType oratype; /* data type in Oracle */ 121 | int scale; /* "scale" type modifier, used for NUMBERs */ 122 | char *pgname; /* PostgreSQL column name */ 123 | int pgattnum; /* PostgreSQL attribute number */ 124 | Oid pgtype; /* PostgreSQL data type */ 125 | int pgtypmod; /* PostgreSQL type modifier */ 126 | int used; /* is the column used in the query? */ 127 | int strip_zeros; /* should ASCII zero be removed from Oracle strings? */ 128 | int pkey; /* nonzero for primary keys, later set to the resjunk attribute number */ 129 | char *val; /* buffer for Oracle to return results in (LOB locators for LOBs) */ 130 | int32_t val_size; /* allocated size of one element in val */ 131 | uint16_t *val_len; /* array of actual lengths of val */ 132 | uint32_t val_len4; /* actual length of val - for bind callbacks */ 133 | int16_t *val_null; /* indicators for NULL values */ 134 | int varno; /* range table index of this column's relation */ 135 | }; 136 | 137 | struct oraTable 138 | { 139 | char *name; /* name in Oracle */ 140 | char *pgname; /* for error messages */ 141 | int ncols; /* number of columns */ 142 | int npgcols; /* number of columns (including dropped) in the PostgreSQL foreign table */ 143 | struct oraColumn **cols; 144 | }; 145 | 146 | /* types to store parameter descriprions */ 147 | 148 | typedef enum { 149 | BIND_STRING, 150 | BIND_NUMBER, 151 | BIND_LONG, 152 | BIND_LONGRAW, 153 | BIND_GEOMETRY, 154 | BIND_OUTPUT 155 | } oraBindType; 156 | 157 | struct paramDesc 158 | { 159 | char *name; /* name we give the parameter */ 160 | Oid type; /* PostgreSQL data type */ 161 | oraBindType bindType; /* which type to use for binding to Oracle statement */ 162 | char *value; /* value rendered for Oracle */ 163 | void *node; /* the executable expression */ 164 | int colnum; /* corresponding column in oraTable (-1 in SELECT queries unless output column) */ 165 | void *bindh; /* bind handle */ 166 | struct paramDesc *next; 167 | }; 168 | 169 | /* PostgreSQL error messages we need */ 170 | typedef enum 171 | { 172 | FDW_ERROR, 173 | FDW_UNABLE_TO_ESTABLISH_CONNECTION, 174 | FDW_UNABLE_TO_CREATE_REPLY, 175 | FDW_UNABLE_TO_CREATE_EXECUTION, 176 | FDW_TABLE_NOT_FOUND, 177 | FDW_OUT_OF_MEMORY, 178 | FDW_SERIALIZATION_FAILURE, 179 | FDW_UNIQUE_VIOLATION, 180 | FDW_DEADLOCK_DETECTED, 181 | FDW_NOT_NULL_VIOLATION, 182 | FDW_CHECK_VIOLATION, 183 | FDW_FOREIGN_KEY_VIOLATION 184 | } oraError; 185 | 186 | /* encapsulates an Oracle geometry object */ 187 | typedef struct 188 | { 189 | struct sdo_geometry *geometry; 190 | struct sdo_geometry_ind *indicator; 191 | /* the following fields are extracted from "geometry" by unpack() */ 192 | int num_elems; /* number of SDO_ELEM_INFO entries, -1 for "not unpacked" */ 193 | unsigned *elem; /* unpacked SDO_ELEM_INFO entries */ 194 | int num_coords; /* number of SDO_ORDINATES entries, -1 for "not unpacked" */ 195 | double *coord; /* unpacked SDO_ORDINATES entries */ 196 | } ora_geometry; 197 | 198 | /* Oracle transaction isolation levels */ 199 | typedef enum 200 | { 201 | ORA_TRANS_READ_COMMITTED, 202 | ORA_TRANS_READ_ONLY, 203 | ORA_TRANS_SERIALIZABLE 204 | } oraIsoLevel; 205 | 206 | /* 207 | * functions defined in oracle_utils.c 208 | */ 209 | extern oracleSession *oracleGetSession(const char *connectstring, oraIsoLevel isolation_level, char *user, char *password, const char *nls_lang, const char *timezone, int have_nchar, const char *tablename, int curlevel); 210 | extern void oracleCloseStatement(oracleSession *session); 211 | extern void oracleCloseConnections(void); 212 | extern void oracleShutdown(void); 213 | extern void oracleCancel(void); 214 | extern void oracleEndTransaction(void *arg, int is_commit, int silent); 215 | extern void oracleEndSubtransaction(void *arg, int nest_level, int is_commit); 216 | extern int oracleIsStatementOpen(oracleSession *session); 217 | extern struct oraTable *oracleDescribe(oracleSession *session, char *dblink, char *schema, char *table, char *pgname, long max_long, int *has_geometry); 218 | extern void oracleExplain(oracleSession *session, const char *query, int *nrows, char ***plan); 219 | extern void oraclePrepareQuery(oracleSession *session, const char *query, const struct oraTable *oraTable, unsigned int prefetch, unsigned int lob_prefetch); 220 | extern unsigned int oracleExecuteQuery(oracleSession *session, const struct oraTable *oraTable, struct paramDesc *paramList, unsigned int prefetch); 221 | extern unsigned int oracleFetchNext(oracleSession *session, unsigned int prefetch); 222 | extern void oracleExecuteCall(oracleSession *session, char * const stmt); 223 | extern void oracleGetLob(oracleSession *session, void *locptr, oraType type, char **value, long *value_len, unsigned long trunc); 224 | extern void oracleClientVersion(int *major, int *minor, int *update, int *patch, int *port_patch); 225 | extern void oracleServerVersion(oracleSession *session, int *major, int *minor, int *update, int *patch, int *port_patch); 226 | extern void *oracleGetGeometryType(oracleSession *session); 227 | extern int oracleGetImportColumn(oracleSession *session, char *dblink, char *schema, char *limit_to, char **tabname, char **colname, oraType *type, int *charlen, int *typeprec, int *typescale, int *nullable, int *key, int skip_tables, int skip_views, int skip_matviews); 228 | 229 | /* 230 | * functions defined in oracle_fdw.c 231 | */ 232 | extern char *oracleGetShareFileName(const char *relativename); 233 | extern void oracleRegisterCallback(void *arg); 234 | extern void oracleUnregisterCallback(void *arg); 235 | extern void *oracleAlloc(size_t size); 236 | extern void *oracleRealloc(void *p, size_t size); 237 | extern void oracleFree(void *p); 238 | extern void oracleSetHandlers(void); 239 | extern void oracleError_d(oraError sqlstate, const char *message, const char *detail); 240 | extern void oracleError_sd(oraError sqlstate, const char *message, const char *arg, const char *detail); 241 | extern void oracleError_ssdh(oraError sqlstate, const char *message, const char *arg1, const char* arg2, const char *detail, const char *hint); 242 | extern void oracleError_ii(oraError sqlstate, const char *message, int arg1, int arg2); 243 | extern void oracleError_i(oraError sqlstate, const char *message, int arg); 244 | extern void oracleError(oraError sqlstate, const char *message); 245 | extern void oracleDebug2(const char *message); 246 | extern void initializePostGIS(void); 247 | 248 | /* 249 | * functions defined in oracle_gis.c 250 | */ 251 | 252 | extern ora_geometry *oracleEWKBToGeom(oracleSession *session, unsigned int ewkb_length, char *ewkb_data); 253 | extern unsigned int oracleGetEWKBLen(oracleSession *session, ora_geometry *geom); 254 | extern char *oracleFillEWKB(oracleSession *session, ora_geometry *geom, unsigned int size, char *dest); 255 | extern void oracleGeometryFree(oracleSession *session, ora_geometry *geom); 256 | extern void oracleGeometryAlloc(oracleSession *session, ora_geometry *geom); 257 | -------------------------------------------------------------------------------- /oracle_gis.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * oracle_gis.c 4 | * routines that convert between Oracle SDO_GEOMETRY and PostGIS EWKB 5 | * 6 | *------------------------------------------------------------------------- 7 | */ 8 | 9 | /* 10 | * The code relies heavily on the PostGIS internal data stucture that is explained 11 | * in g_serialized.txt in the PostGIS source code and implemented in liblwgeom.h. 12 | */ 13 | 14 | /* Oracle header */ 15 | #include 16 | 17 | #include 18 | #include 19 | #include 20 | #include 21 | 22 | #include "oracle_fdw.h" 23 | 24 | #define POINTTYPE 1 25 | #define LINETYPE 2 26 | #define POLYGONTYPE 3 27 | #define MULTIPOINTTYPE 4 28 | #define MULTILINETYPE 5 29 | #define MULTIPOLYGONTYPE 6 30 | #define COLLECTIONTYPE 7 31 | #define CIRCSTRINGTYPE 8 32 | #define COMPOUNDTYPE 9 33 | #define CURVEPOLYTYPE 10 34 | #define MULTICURVETYPE 11 35 | #define MULTISURFACETYPE 12 36 | #define POLYHEDRALSURFACETYPE 13 37 | #define TRIANGLETYPE 14 38 | #define TINTYPE 15 39 | 40 | #define WKBSRIDFLAG 0x20000000 41 | #define WKBZOFFSET 0x80000000 42 | #define WKBMOFFSET 0x40000000 43 | 44 | #define uintToNumber(errhp, intp, numberp) { \ 45 | if (checkerr( \ 46 | OCINumberFromInt((errhp), (dvoid *)(intp), sizeof(unsigned), OCI_NUMBER_UNSIGNED, (numberp)), \ 47 | (errhp)) != OCI_SUCCESS) \ 48 | oracleError_d(FDW_ERROR, "OCINumberFromInt failed to convert integer to NUMBER", oraMessage); \ 49 | } 50 | 51 | #define numberToUint(errhp, numberp, intp) { \ 52 | if (checkerr( \ 53 | OCINumberToInt((errhp), (numberp), sizeof(unsigned), OCI_NUMBER_UNSIGNED, (dvoid *)(intp)), \ 54 | (errhp)) != OCI_SUCCESS) \ 55 | oracleError_d(FDW_ERROR, "OCINumberToInt failed to convert NUMBER to integer", oraMessage); \ 56 | } 57 | 58 | #define doubleToNumber(errhp, doublep, numberp) { \ 59 | if (checkerr( \ 60 | OCINumberFromReal((errhp), (const dvoid *)(doublep), sizeof(double), (numberp)), \ 61 | (errhp)) != OCI_SUCCESS) \ 62 | oracleError_d(FDW_ERROR, "OCINumberFromReal failed to convert floating point number to NUMBER", oraMessage); \ 63 | } 64 | 65 | #define numberToDouble(errhp, numberp, doublep) { \ 66 | if (checkerr( \ 67 | OCINumberToReal((errhp), (numberp), sizeof(double), (dvoid *)(doublep)), \ 68 | (errhp)) != OCI_SUCCESS) \ 69 | oracleError_d(FDW_ERROR, "OCINumberToReal failed to convert NUMBER to floating point number", oraMessage); \ 70 | } 71 | 72 | /* file for mapping SRIDs in the "share" directory */ 73 | #define SRID_MAP_FILE "srid.map" 74 | 75 | typedef struct 76 | { 77 | unsigned from; /* != 0 for valid ones */ 78 | unsigned to; 79 | } mapEntry; 80 | 81 | #define mapEntryValid(x) ((x)->from != 0) 82 | 83 | /* maps Oracle SRIDs to PostGIS SRIDs */ 84 | static mapEntry *srid_map = NULL; 85 | 86 | /* contains Oracle error messages, set by checkerr() */ 87 | #define ERRBUFSIZE 500 88 | static char oraMessage[ERRBUFSIZE]; 89 | static sb4 err_code; 90 | 91 | /* 92 | * Structures needed for managing the MDSYS.SDO_GEOMETRY Oracle type. 93 | * Most of these were generated with OTT. 94 | */ 95 | typedef struct 96 | { 97 | OCINumber x; 98 | OCINumber y; 99 | OCINumber z; 100 | } sdo_point_type; 101 | 102 | typedef struct 103 | { 104 | OCIInd _atomic; 105 | OCIInd x; 106 | OCIInd y; 107 | OCIInd z; 108 | } sdo_point_type_ind; 109 | 110 | typedef struct sdo_geometry 111 | { 112 | OCINumber sdo_gtype; 113 | OCINumber sdo_srid; 114 | sdo_point_type sdo_point; 115 | OCIArray *sdo_elem_info; 116 | OCIArray *sdo_ordinates; 117 | } sdo_geometry; 118 | 119 | typedef struct sdo_geometry_ind 120 | { 121 | OCIInd _atomic; 122 | OCIInd sdo_gtype; 123 | OCIInd sdo_srid; 124 | sdo_point_type_ind sdo_point; 125 | OCIInd sdo_elem_info; 126 | OCIInd sdo_ordinates; 127 | } sdo_geometry_ind; 128 | 129 | static unsigned ewkbType(oracleSession *session, ora_geometry *geom); 130 | static unsigned sdoDimension(oracleSession *session, ora_geometry *geom); 131 | static unsigned ewkbIsMeasured(oracleSession *session, ora_geometry *geom); 132 | static unsigned ewkbSrid(oracleSession *session, ora_geometry *geom); 133 | static unsigned numCoord(oracleSession *session, ora_geometry *geom); 134 | static double coord(oracleSession *session, ora_geometry *geom, unsigned i); 135 | static unsigned numElemInfo(oracleSession *session, ora_geometry *geom); 136 | static unsigned elemInfo(oracleSession *session, ora_geometry *geom, unsigned i); 137 | static void appendElemInfo(oracleSession *session, ora_geometry *geom, unsigned info ); 138 | static void appendCoord(oracleSession *session, ora_geometry *geom, double coord); 139 | static char *doubleFill(double x, char * dest); 140 | static char *unsignedFill(unsigned i, char * dest); 141 | static sword checkerr(sword status, OCIError *handle); 142 | static void initSRIDMap(void); 143 | static unsigned epsgFromOracle(unsigned srid); 144 | static unsigned epsgToOracle(unsigned srid); 145 | static void unpack(oracleSession *session, ora_geometry *geom); 146 | static void freeUnpacked(oracleSession *session, ora_geometry *geom); 147 | 148 | /* All ...Fill() functions return a pointer to the end of the written zone 149 | */ 150 | static unsigned ewkbHeaderLen(oracleSession *session, ora_geometry *geom); 151 | static char *ewkbHeaderFill(oracleSession *session, ora_geometry *geom, char * dest); 152 | static unsigned ewkbPointLen(oracleSession *session, ora_geometry *geom); 153 | static char *ewkbPointFill(oracleSession *session, ora_geometry *geom, char *dest); 154 | static unsigned ewkbLineLen(oracleSession *session, ora_geometry *geom); 155 | static char *ewkbLineFill(oracleSession *session, ora_geometry *geom, char * dest); 156 | static unsigned ewkbPolygonLen(oracleSession *session, ora_geometry *geom); 157 | static char *ewkbPolygonFill(oracleSession *session, ora_geometry *geom, char * dest); 158 | static unsigned ewkbMultiPointLen(oracleSession *session, ora_geometry *geom); 159 | static char *ewkbMultiPointFill(oracleSession *session, ora_geometry *geom, char *dest); 160 | static unsigned ewkbMultiLineLen(oracleSession *session, ora_geometry *geom); 161 | static char *ewkbMultiLineFill(oracleSession *session, ora_geometry *geom, char * dest); 162 | static unsigned ewkbMultiPolygonLen(oracleSession *session, ora_geometry *geom); 163 | static char *ewkbMultiPolygonFill(oracleSession *session, ora_geometry *geom, char * dest); 164 | 165 | /* 166 | * All the set...() functions return a pointer that points to a position in the 167 | * input buffer right after the added data. 168 | * That way we can call several of them in a row and even nest them, 169 | * like in the case of a multipolygon composed of several polygons. 170 | */ 171 | static const char *setType(oracleSession *session, ora_geometry *geom, const char *data); 172 | static const char *setSridAndFlags(oracleSession *session, ora_geometry *geom, const char *data); 173 | static const char *setPoint(oracleSession *session, ora_geometry *geom, const char *data); 174 | static const char *setLine(oracleSession *session, ora_geometry *geom, const char *data); 175 | static const char *setPolygon(oracleSession *session, ora_geometry *geom, const char *data); 176 | static const char *setMultiPoint(oracleSession *session, ora_geometry *geom, const char *data); 177 | static const char *setMultiLine(oracleSession *session, ora_geometry *geom, const char *data); 178 | static const char *setMultiPolygon(oracleSession *session, ora_geometry *geom, const char *data); 179 | 180 | char * 181 | doubleFill(double x, char * dest) 182 | { 183 | memcpy(dest, &x, sizeof(double)); 184 | dest += sizeof(double); 185 | return dest; 186 | } 187 | 188 | char * 189 | unsignedFill(unsigned i, char * dest) 190 | { 191 | memcpy(dest, &i, sizeof(unsigned)); 192 | dest += sizeof(unsigned); 193 | return dest; 194 | } 195 | 196 | /* 197 | * initSRIDMap 198 | * Allocates "srid_map" and reads the SRID map file into it. 199 | */ 200 | void 201 | initSRIDMap() 202 | { 203 | char *mapFileName = NULL; 204 | FILE *mapFile; 205 | char line[20]; 206 | unsigned long from, to; 207 | int count = 0, i, save_errno, c; 208 | 209 | mapFileName = oracleGetShareFileName(SRID_MAP_FILE); 210 | 211 | /* initialize "srid_map" with an invalid entry */ 212 | srid_map = (mapEntry *)malloc(sizeof(mapEntry)); 213 | if (srid_map == NULL) 214 | oracleError_i(FDW_ERROR, "failed to allocate %d bytes of memory", sizeof(mapEntry)); 215 | srid_map[0].from = 0; 216 | 217 | /* from here on we must make sure that srid_map is reset to NULL if an error occurs */ 218 | 219 | errno = 0; 220 | if ((mapFile = fopen(mapFileName, "r")) == NULL) 221 | { 222 | /* if the file does not exist, treat it as if it were empty */ 223 | if (errno == ENOENT) 224 | return; 225 | 226 | /* other errors are reported */ 227 | free(srid_map); 228 | srid_map = NULL; 229 | oracleError(FDW_ERROR, "cannot open file \"" SRID_MAP_FILE "\": %m"); 230 | } 231 | 232 | /* from here on we must make sure that mapFile is closed if an error happens */ 233 | oracleFree(mapFileName); 234 | 235 | do 236 | { 237 | /* read the next line into "line" */ 238 | i = 0; 239 | do 240 | { 241 | c = fgetc(mapFile); 242 | 243 | if (c == '\n' || c == EOF) 244 | { 245 | line[i] = '\0'; 246 | } 247 | else 248 | { 249 | if (i >= 19) 250 | { 251 | (void)fclose(mapFile); 252 | free(srid_map); 253 | srid_map = NULL; 254 | oracleError(FDW_ERROR, 255 | "syntax error in file \"" SRID_MAP_FILE "\": line too long"); 256 | } 257 | line[i++] = c; 258 | } 259 | } while (c != '\n' && c != EOF); 260 | 261 | /* ignore empty lines */ 262 | if (*line == '\0') 263 | continue; 264 | 265 | /* read two unsigned integers */ 266 | i = sscanf(line, "%lu %lu", &from, &to); 267 | if (i == EOF) 268 | { 269 | save_errno = errno; 270 | (void)fclose(mapFile); 271 | errno = save_errno; 272 | free(srid_map); 273 | srid_map = NULL; 274 | oracleError(FDW_ERROR, "syntax error in file \"" SRID_MAP_FILE "\": %m"); 275 | } 276 | if (i != 2) 277 | { 278 | (void)fclose(mapFile); 279 | free(srid_map); 280 | srid_map = NULL; 281 | oracleError(FDW_ERROR, 282 | "syntax error in file \"" SRID_MAP_FILE "\": line does not contain two numbers"); 283 | } 284 | if (from == 0 || to == 0) 285 | { 286 | (void)fclose(mapFile); 287 | free(srid_map); 288 | srid_map = NULL; 289 | oracleError(FDW_ERROR, 290 | "syntax error in file \"" SRID_MAP_FILE "\": SRID cannot be zero"); 291 | } 292 | if (from > 0xffffffff || to > 0xffffffff) 293 | { 294 | (void)fclose(mapFile); 295 | free(srid_map); 296 | srid_map = NULL; 297 | oracleError(FDW_ERROR, 298 | "syntax error in file \"" SRID_MAP_FILE "\": number too large"); 299 | } 300 | 301 | /* add a new mapEntry to srid_map */ 302 | srid_map = (mapEntry *)realloc(srid_map, sizeof(mapEntry) * (++count + 1)); 303 | if (srid_map == NULL) 304 | { 305 | (void)fclose(mapFile); 306 | free(srid_map); 307 | srid_map = NULL; 308 | oracleError_i(FDW_ERROR, "failed to allocate %d bytes of memory", sizeof(mapEntry) * (count + 1)); 309 | } 310 | 311 | srid_map[count - 1].from = (unsigned)from; 312 | srid_map[count - 1].to = (unsigned)to; 313 | srid_map[count].from = 0; 314 | } while (c != EOF); 315 | 316 | /* check for errors */ 317 | save_errno = errno; 318 | (void)fclose(mapFile); 319 | errno = save_errno; 320 | 321 | if (errno) 322 | { 323 | free(srid_map); 324 | srid_map = NULL; 325 | oracleError(FDW_ERROR, "error reading from file \"" SRID_MAP_FILE "\": %m"); 326 | } 327 | } 328 | 329 | unsigned 330 | epsgFromOracle(unsigned srid) 331 | { 332 | mapEntry *entry; 333 | 334 | if (srid_map == NULL) 335 | initSRIDMap(); 336 | 337 | for (entry = srid_map; mapEntryValid(entry); ++entry) 338 | if (entry->from == srid) 339 | return entry->to; 340 | 341 | return srid; 342 | } 343 | 344 | unsigned 345 | epsgToOracle(unsigned srid) 346 | { 347 | mapEntry *entry; 348 | 349 | if (srid_map == NULL) 350 | initSRIDMap(); 351 | 352 | for (entry = srid_map; mapEntryValid(entry); ++entry) 353 | if (entry->to == srid) 354 | return entry->from; 355 | 356 | return srid; 357 | } 358 | 359 | /* 360 | * oracleEWKBToGeom 361 | * Creates an Oracle SDO_GEOMETRY from a PostGIS EWKB. 362 | * The result is a partially palloc'ed structure. 363 | * Zero length or a NULL pointer for ewkb_data yield an atomically NULL object. 364 | */ 365 | ora_geometry * 366 | oracleEWKBToGeom(oracleSession *session, unsigned ewkb_length, char *ewkb_data) 367 | { 368 | const char *data = ewkb_data; 369 | unsigned type; 370 | 371 | ora_geometry *geom = (ora_geometry *)oracleAlloc(sizeof(ora_geometry)); 372 | oracleGeometryAlloc(session, geom); 373 | geom->num_elems = -1; 374 | geom->elem = NULL; 375 | geom->num_coords = -1; 376 | geom->coord = NULL; 377 | 378 | /* for NULL data, return an object that is atomically NULL */ 379 | if (data == NULL || ewkb_length == 0) 380 | return geom; 381 | else 382 | geom->indicator->_atomic = OCI_IND_NOTNULL; 383 | 384 | data = setSridAndFlags(session, geom, data); 385 | 386 | /* 387 | * We don't move the data pointer after this call because 388 | * it will be moved after the following setTYPE functions 389 | * and those functions expect the data pointer to be on the 390 | * type and not after (see comment above about g_serialized.txt 391 | * and set... functions). 392 | */ 393 | setType(session, geom, data); 394 | 395 | type = ewkbType(session, geom); 396 | 397 | /* these will be NULL for points */ 398 | geom->indicator->sdo_ordinates = (type == POINTTYPE) ? OCI_IND_NULL : OCI_IND_NOTNULL; 399 | geom->indicator->sdo_elem_info = (type == POINTTYPE) ? OCI_IND_NULL : OCI_IND_NOTNULL; 400 | 401 | switch (type) 402 | { 403 | case POINTTYPE: 404 | data = setPoint(session, geom, data); 405 | break; 406 | case LINETYPE: 407 | data = setLine(session, geom, data); 408 | break; 409 | case POLYGONTYPE: 410 | data = setPolygon(session, geom, data); 411 | break; 412 | case MULTIPOINTTYPE: 413 | data = setMultiPoint(session, geom, data); 414 | break; 415 | case MULTILINETYPE: 416 | data = setMultiLine(session, geom, data); 417 | break; 418 | case MULTIPOLYGONTYPE: 419 | data = setMultiPolygon(session, geom, data); 420 | break; 421 | default: 422 | oracleError_i(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: unexpected geometry type %u", type); 423 | } 424 | 425 | /* check that we reached the end of input data */ 426 | if (data - ewkb_data != ewkb_length) 427 | oracleError_ii(FDW_ERROR, "oracle_fdw internal error: number of bytes read %u is different from length %u", data - ewkb_data, ewkb_length); 428 | 429 | return geom; 430 | } 431 | 432 | /* 433 | * oracleGetEWKBLen 434 | * Returns the length in bytes needed to store an EWKB conversion of "geom". 435 | */ 436 | unsigned 437 | oracleGetEWKBLen(oracleSession *session, ora_geometry *geom) 438 | { 439 | unsigned type; 440 | 441 | /* return zero length for atomically NULL objects */ 442 | if (geom->indicator->_atomic == OCI_IND_NULL) 443 | return 0; 444 | 445 | /* unpack SDO_ELEM_INFO and SDO_ORDINATES */ 446 | if (geom->num_elems == -1) 447 | unpack(session, geom); 448 | 449 | /* a first check for supported types is done in ewkbType */ 450 | type = ewkbType(session, geom); 451 | 452 | /* 453 | * If sdo_elem_info is NOT NULL, we go through and check that the 454 | * type and interpretation are actually supported. 455 | */ 456 | if (geom->indicator->sdo_elem_info == OCI_IND_NOTNULL) 457 | { 458 | const unsigned n = geom->num_elems; 459 | unsigned i; 460 | for (i=0; ielem[i+1]; 462 | const unsigned interpretation = geom->elem[i+2]; 463 | if (!((1 == etype && 1 == interpretation) 464 | ||(2 == etype && 1 == interpretation) 465 | ||(1003 == etype && 1 == interpretation) 466 | ||(2003 == etype && 1 == interpretation) 467 | )) 468 | oracleError_ii(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: unsupported etype %u with interpretation %u in elem_info", etype, interpretation); 469 | } 470 | } 471 | 472 | switch (type) 473 | { 474 | case POINTTYPE: 475 | return ewkbHeaderLen(session, geom) + ewkbPointLen(session, geom); 476 | case LINETYPE: 477 | return ewkbHeaderLen(session, geom) + ewkbLineLen(session, geom); 478 | case POLYGONTYPE: 479 | return ewkbHeaderLen(session, geom) + ewkbPolygonLen(session, geom); 480 | case MULTIPOINTTYPE: 481 | return ewkbHeaderLen(session, geom) + ewkbMultiPointLen(session, geom); 482 | case MULTILINETYPE: 483 | return ewkbHeaderLen(session, geom) + ewkbMultiLineLen(session, geom); 484 | case MULTIPOLYGONTYPE: 485 | return ewkbHeaderLen(session, geom) + ewkbMultiPolygonLen(session, geom); 486 | default: 487 | oracleError_i(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: unexpected geometry type %u", type); 488 | return 0; /* unreachable, but keeps compiler happy */ 489 | } 490 | } 491 | 492 | /* 493 | * oracleFillEWKB 494 | * Converts "geom" to an EWKB and stores the result in "dest". 495 | */ 496 | char * 497 | oracleFillEWKB(oracleSession *session, ora_geometry *geom, unsigned size, char *dest) 498 | { 499 | const char *orig = dest; 500 | unsigned type; 501 | 502 | dest = ewkbHeaderFill(session, geom, dest); 503 | switch ((type = ewkbType(session, geom))) 504 | { 505 | case POINTTYPE: 506 | dest = ewkbPointFill(session, geom, dest); 507 | break; 508 | case LINETYPE: 509 | dest = ewkbLineFill(session, geom, dest); 510 | break; 511 | case POLYGONTYPE: 512 | dest = ewkbPolygonFill(session, geom, dest); 513 | break; 514 | case MULTIPOINTTYPE: 515 | dest = ewkbMultiPointFill(session, geom, dest); 516 | break; 517 | case MULTILINETYPE: 518 | dest = ewkbMultiLineFill(session, geom, dest); 519 | break; 520 | case MULTIPOLYGONTYPE: 521 | dest = ewkbMultiPolygonFill(session, geom, dest); 522 | break; 523 | default: 524 | oracleError_i(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: unexpected geometry type %u", type); 525 | } 526 | 527 | /* check that we have reached the end of the input buffer */ 528 | if (dest - orig != size) 529 | oracleError_ii(FDW_ERROR, "oracle_fdw internal error: number of bytes written %u is different from size %u", dest - orig, size); 530 | 531 | /* free memory in unpacked geometry */ 532 | if (geom->num_elems != -1) 533 | freeUnpacked(session, geom); 534 | 535 | return dest; 536 | } 537 | 538 | /* 539 | * oracleGeometryFree 540 | * Free the memory allocated with a geometry object. 541 | */ 542 | void 543 | oracleGeometryFree(oracleSession *session, ora_geometry *geom) 544 | { 545 | /* 546 | * From the OCI documentation: 547 | * If there is a top-level object (as with a non-atomically NULL object), 548 | * then the indicator is freed when the top-level object is freed with OCIObjectFree(). 549 | * If the object is atomically null, then there is no top-level object, 550 | * so the indicator must be freed separately. 551 | */ 552 | if (geom->geometry != NULL && geom->indicator->_atomic == OCI_IND_NOTNULL) 553 | (void)OCIObjectFree(session->envp->envhp, session->envp->errhp, geom->geometry, 0); 554 | else 555 | (void)OCIObjectFree(session->envp->envhp, session->envp->errhp, geom->indicator, 0); 556 | 557 | geom->geometry = NULL; 558 | geom->indicator = NULL; 559 | } 560 | 561 | /* 562 | * oracleGeometryAlloc 563 | * Allocate memory for a geometry object in the Oracle object cache. 564 | * The indicator is set to atomic NULL. 565 | */ 566 | void 567 | oracleGeometryAlloc(oracleSession *session, ora_geometry *geom) 568 | { 569 | /* allocate a SDO_GEOMETRY object */ 570 | if (checkerr( 571 | OCIObjectNew(session->envp->envhp, 572 | session->envp->errhp, 573 | session->connp->svchp, 574 | OCI_TYPECODE_OBJECT, 575 | oracleGetGeometryType(session), 576 | (dvoid *)NULL, 577 | OCI_DURATION_TRANS, 578 | TRUE, 579 | (dvoid **)&geom->geometry), 580 | session->envp->errhp) != OCI_SUCCESS) 581 | oracleError_d(FDW_ERROR, "cannot allocate SDO_GEOMETRY object", oraMessage); 582 | 583 | /* get the NULL indicator */ 584 | if (checkerr( 585 | OCIObjectGetInd(session->envp->envhp, 586 | session->envp->errhp, 587 | geom->geometry, 588 | (void **)&geom->indicator), 589 | session->envp->errhp) != OCI_SUCCESS) 590 | oracleError_d(FDW_ERROR, "cannot get indicator for new SDO_GEOMETRY object", oraMessage); 591 | 592 | /* initialize as atomic NULL */ 593 | geom->indicator->_atomic = OCI_IND_NULL; 594 | } 595 | 596 | void 597 | appendElemInfo(oracleSession *session, ora_geometry *geom, unsigned info) 598 | { 599 | OCINumber n; 600 | 601 | uintToNumber(session->envp->errhp, &info, &n); 602 | 603 | if (checkerr( 604 | OCICollAppend(session->envp->envhp, 605 | session->envp->errhp, 606 | (CONST dvoid*) &n, 607 | NULL, 608 | geom->geometry->sdo_elem_info), 609 | session->envp->errhp) != OCI_SUCCESS) 610 | oracleError_d(FDW_ERROR, "cannot append to element info collection", oraMessage); 611 | } 612 | 613 | void 614 | appendCoord(oracleSession *session, ora_geometry *geom, double coord) 615 | { 616 | OCINumber n; 617 | 618 | doubleToNumber(session->envp->errhp, &coord, &n); 619 | if (checkerr( 620 | OCICollAppend(session->envp->envhp, 621 | session->envp->errhp, 622 | (CONST dvoid*) &n, 623 | NULL, 624 | geom->geometry->sdo_ordinates), 625 | session->envp->errhp) != OCI_SUCCESS) 626 | oracleError_d(FDW_ERROR, "cannot append to ordinate collection", oraMessage); 627 | } 628 | 629 | unsigned 630 | ewkbType(oracleSession *session, ora_geometry *geom) 631 | { 632 | unsigned gtype = 0; 633 | if (geom->indicator->sdo_gtype == OCI_IND_NULL) 634 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: geometry type cannot be NULL"); 635 | 636 | numberToUint(session->envp->errhp, &(geom->geometry->sdo_gtype), >ype); 637 | 638 | switch (gtype%100) 639 | { 640 | case 1: 641 | return POINTTYPE; 642 | case 2: 643 | return LINETYPE; 644 | case 3: 645 | return POLYGONTYPE; 646 | case 4: 647 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: geometry type COLLECTION not supported"); 648 | break; 649 | case 5: 650 | return MULTIPOINTTYPE; 651 | case 6: 652 | return MULTILINETYPE; 653 | case 7: 654 | return MULTIPOLYGONTYPE; 655 | case 8: 656 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: geometry type SOLID not supported"); 657 | break; 658 | case 9: 659 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: geometry type MULTISOLID not supported"); 660 | break; 661 | default: 662 | oracleError_i(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: unknown geometry type %u", gtype); 663 | } 664 | return 0; /* unreachable, but keeps compiler happy */ 665 | } 666 | 667 | const char * 668 | setType(oracleSession *session, ora_geometry *geom, const char *data) 669 | { 670 | const ub4 wkbType = *((ub4 *)data); 671 | unsigned gtype; 672 | 673 | numberToUint(session->envp->errhp, &(geom->geometry->sdo_gtype), >ype); 674 | 675 | data += sizeof(ub4); 676 | 677 | switch (wkbType) 678 | { 679 | case POINTTYPE: 680 | gtype += 1; 681 | break; 682 | case LINETYPE: 683 | gtype += 2; 684 | break; 685 | case POLYGONTYPE: 686 | gtype += 3; 687 | break; 688 | case MULTIPOINTTYPE: 689 | gtype += 5; 690 | break; 691 | case MULTILINETYPE: 692 | gtype += 6; 693 | break; 694 | case MULTIPOLYGONTYPE: 695 | gtype += 7; 696 | break; 697 | #define UNSUPPORTED_TYPE( T ) case T ## TYPE: oracleError(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: geometry type "#T" not supported"); break; 698 | UNSUPPORTED_TYPE(COLLECTION) 699 | UNSUPPORTED_TYPE(CIRCSTRING) 700 | UNSUPPORTED_TYPE(COMPOUND) 701 | UNSUPPORTED_TYPE(CURVEPOLY) 702 | UNSUPPORTED_TYPE(MULTICURVE) 703 | UNSUPPORTED_TYPE(MULTISURFACE) 704 | UNSUPPORTED_TYPE(POLYHEDRALSURFACE) 705 | UNSUPPORTED_TYPE(TRIANGLE) 706 | UNSUPPORTED_TYPE(TIN) 707 | #undef UNSUPPORTED_TYPE 708 | default: 709 | oracleError_i(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: unknown geometry type %u", wkbType); 710 | } 711 | 712 | geom->indicator->sdo_gtype = OCI_IND_NOTNULL; 713 | uintToNumber(session->envp->errhp, >ype, &(geom->geometry->sdo_gtype)); 714 | 715 | return data; 716 | } 717 | 718 | /* 719 | * Header contains: 720 | * - srid : 3 bytes 721 | * - flags : 1 byte 722 | */ 723 | unsigned 724 | ewkbHeaderLen(oracleSession *session, ora_geometry *geom) 725 | { 726 | return 4; 727 | } 728 | 729 | char * 730 | ewkbHeaderFill(oracleSession *session, ora_geometry *geom, char * dest) 731 | { 732 | const unsigned srid = ewkbSrid(session, geom); 733 | const unsigned sdoDim = sdoDimension(session, geom); 734 | ub1 flags; 735 | ub1 s[3]; 736 | 737 | if (sdoDim > 3) 738 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: four-dimensional geometries are unsupported"); 739 | 740 | if (ewkbIsMeasured(session, geom)) 741 | /* 742 | * In Oracle, the measure dimension counts as third dimension, 743 | * so "sdoDim" will be 3. This corresponds to a two-dimensional 744 | * PostGIS geometry with the "measure" flag set. 745 | */ 746 | flags = 0x02; 747 | else 748 | flags = ((3 == sdoDim) ? 0x01 : 0x00 ); 749 | 750 | s[0] = (srid & 0x001F0000) >> 16; 751 | s[1] = (srid & 0x0000FF00) >> 8; 752 | s[2] = (srid & 0x000000FF); 753 | 754 | memcpy(dest, s, 3); 755 | dest += 3; 756 | memcpy(dest, &flags, 1); 757 | dest += 1; 758 | return dest; 759 | } 760 | 761 | unsigned 762 | ewkbIsMeasured(oracleSession *session, ora_geometry *geom) 763 | { 764 | unsigned gtype = 0; 765 | if (geom->indicator->sdo_gtype == OCI_IND_NOTNULL) 766 | numberToUint(session->envp->errhp, &(geom->geometry->sdo_gtype), >ype); 767 | switch ((gtype % 1000) / 100) 768 | { 769 | case 0: 770 | return 0; 771 | case 3: 772 | return 1; 773 | default: 774 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: measure dimension must be \"0\" or \"3\""); 775 | return 0; /* keep the compiler happy */ 776 | } 777 | } 778 | 779 | /* 780 | * sdoDimension 781 | * Returns the dimension as Oracle understands it. 782 | * For a measured geometry with two dimensions and one measure dimension, 783 | * it will return 3 (PostGIS considers such an object two-dimensional). 784 | */ 785 | unsigned 786 | sdoDimension(oracleSession *session, ora_geometry *geom) 787 | { 788 | unsigned gtype = 0; 789 | if (geom->indicator->sdo_gtype == OCI_IND_NOTNULL) 790 | numberToUint(session->envp->errhp, &(geom->geometry->sdo_gtype), >ype); 791 | return gtype / 1000; 792 | } 793 | 794 | unsigned 795 | ewkbSrid(oracleSession *session, ora_geometry *geom) 796 | { 797 | unsigned srid = 0; 798 | if (geom->indicator->sdo_srid == OCI_IND_NOTNULL) 799 | numberToUint(session->envp->errhp, &(geom->geometry->sdo_srid), &srid); 800 | 801 | /* convert Oracle->PostGIS SRID when needed */ 802 | return epsgFromOracle(srid); 803 | } 804 | 805 | const char * 806 | setSridAndFlags(oracleSession *session, ora_geometry *geom, const char *data) 807 | { 808 | unsigned srid = 0; 809 | unsigned gtype = 0; 810 | 811 | srid |= ((ub1)data[0]) << 16; 812 | srid |= ((ub1)data[1]) << 8; 813 | srid |= ((ub1)data[2]); 814 | /* 815 | * Only the first 21 bits are set. Slide up and back to pull 816 | * the negative bits down, if we need them. 817 | */ 818 | srid = (srid<<11)>>11; 819 | 820 | data += 3; 821 | 822 | /* convert PostGIS->Oracle SRID when needed */ 823 | srid = epsgToOracle(srid); 824 | 825 | geom->indicator->sdo_srid = (srid == 0) ? OCI_IND_NULL : OCI_IND_NOTNULL; 826 | 827 | if (geom->indicator->sdo_srid == OCI_IND_NOTNULL) 828 | uintToNumber(session->envp->errhp, &srid, &(geom->geometry->sdo_srid)); 829 | 830 | gtype = (((ub1)data[0]) & 0x01 ) ? 3000 : 2000; /* 3d/2d */ 831 | if (data[0] & 0x02) 832 | { 833 | /* 834 | * What PostGIS sees as a two-dimensional geometry with measure 835 | * is a three-dimensional geometry in Oracle, and the measure 836 | * dimension is the third dimension. 837 | */ 838 | gtype += 1300; 839 | 840 | if (gtype >= 4000) 841 | oracleError(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: measure dimension only supported for two-dimensional geometries"); 842 | } 843 | if (data[0] & 0x08) 844 | oracleError(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: geodetic not supported"); 845 | 846 | if (((ub1)data[0]) & 0x04) /* has bbox, offsets */ 847 | { 848 | data += 1 + 2*(gtype / 1000)*sizeof(float); 849 | } 850 | else 851 | { 852 | data += 1; 853 | } 854 | 855 | geom->indicator->sdo_gtype = OCI_IND_NOTNULL; 856 | 857 | uintToNumber(session->envp->errhp, >ype, &(geom->geometry->sdo_gtype)); 858 | 859 | return data; 860 | } 861 | 862 | unsigned 863 | ewkbPointLen(oracleSession *session, ora_geometry *geom) 864 | { 865 | return 2*sizeof(unsigned) + sizeof(double)*sdoDimension(session, geom); 866 | } 867 | 868 | char * 869 | ewkbPointFill(oracleSession *session, ora_geometry *geom, char *dest) 870 | { 871 | unsigned dim = sdoDimension(session, geom); 872 | dest = unsignedFill(POINTTYPE, dest); 873 | dest = unsignedFill(1, dest); 874 | 875 | if (geom->indicator->sdo_point._atomic != OCI_IND_NOTNULL) 876 | { 877 | /* the point must be stored in SDO_ORDINATES */ 878 | unsigned offset, etype, interpretation; 879 | double *doubleDest = (double *)dest; 880 | 881 | if (geom->indicator->sdo_elem_info != OCI_IND_NOTNULL) 882 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: SDO_POINT and SDO_ELEM_INFO cannot both be NULL for a point"); 883 | if (geom->indicator->sdo_ordinates != OCI_IND_NOTNULL) 884 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: SDO_POINT and SDO_ORDINATES cannot both be NULL for a point"); 885 | 886 | if (geom->num_elems < 3) 887 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: not enough values in SDO_ELEM_INFO"); 888 | 889 | offset = geom->elem[0]; 890 | etype = geom->elem[1]; 891 | interpretation = geom->elem[2]; 892 | 893 | if (etype != 1) 894 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: point cannot have ETYPE different from 1"); 895 | if (interpretation != 1) 896 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: point with SDO_INTERPRETATION different from 1 is not supported"); 897 | 898 | *doubleDest = geom->coord[offset - 1]; 899 | *(++doubleDest) = geom->coord[offset]; 900 | dest += 2 * sizeof(double); 901 | if (dim == 3) { 902 | *(++doubleDest) = geom->coord[offset + 1]; 903 | dest += sizeof(double); 904 | } 905 | } 906 | else 907 | { 908 | /* the point must be stored in SDO_POINT */ 909 | if (geom->indicator->sdo_point.x != OCI_IND_NOTNULL 910 | || geom->indicator->sdo_point.y != OCI_IND_NOTNULL 911 | || (dim == 3 912 | && geom->indicator->sdo_point.z != OCI_IND_NOTNULL)) 913 | { 914 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: null point coordinates not supported"); 915 | } 916 | 917 | numberToDouble(session->envp->errhp, &(geom->geometry->sdo_point.x), dest); 918 | dest += sizeof(double); 919 | numberToDouble(session->envp->errhp, &(geom->geometry->sdo_point.y), dest); 920 | dest += sizeof(double); 921 | if (3 == dim) 922 | { 923 | numberToDouble(session->envp->errhp, &(geom->geometry->sdo_point.z), dest); 924 | dest += sizeof(double); 925 | } 926 | } 927 | 928 | return dest; 929 | } 930 | 931 | const char * 932 | setPoint(oracleSession *session, ora_geometry *geom, const char *data) 933 | { 934 | if (*((unsigned *)data) != POINTTYPE) 935 | oracleError_i(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: expected point, got type %u", *((unsigned *)data)); 936 | data += sizeof(unsigned); 937 | if (*((unsigned *)data ) != 1) 938 | oracleError(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: empty point is not supported"); 939 | data += sizeof(unsigned); 940 | 941 | geom->indicator->sdo_point._atomic = OCI_IND_NOTNULL; 942 | 943 | geom->indicator->sdo_point.x = OCI_IND_NOTNULL; 944 | doubleToNumber(session->envp->errhp, data, &(geom->geometry->sdo_point.x)); 945 | data += sizeof(double); 946 | geom->indicator->sdo_point.y = OCI_IND_NOTNULL; 947 | doubleToNumber(session->envp->errhp, data, &(geom->geometry->sdo_point.y)); 948 | data += sizeof(double); 949 | if (3 == sdoDimension(session, geom)) 950 | { 951 | geom->indicator->sdo_point.z = OCI_IND_NOTNULL; 952 | doubleToNumber(session->envp->errhp, data, &(geom->geometry->sdo_point.z)); 953 | data += sizeof(double); 954 | } 955 | return data; 956 | } 957 | 958 | unsigned 959 | ewkbLineLen(oracleSession *session, ora_geometry *geom) 960 | { 961 | return 2 * sizeof(unsigned) + sizeof(double) * geom->num_coords; 962 | } 963 | 964 | char * 965 | ewkbLineFill(oracleSession *session, ora_geometry *geom, char * dest) 966 | { 967 | unsigned i; 968 | const unsigned numC = geom->num_coords; 969 | const unsigned numPoints = numC / sdoDimension(session, geom); 970 | dest = unsignedFill(LINETYPE, dest); 971 | dest = unsignedFill(numPoints, dest); 972 | for (i=0; icoord[i], dest); 973 | return dest; 974 | } 975 | 976 | const char * 977 | setLine(oracleSession *session, ora_geometry *geom, const char *data) 978 | { 979 | unsigned i, n; 980 | 981 | if (*((unsigned *)data) != LINETYPE) 982 | oracleError_i(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: expected line, got type %u", *((unsigned *)data)); 983 | data += sizeof(unsigned); 984 | n = *((unsigned *)data) * sdoDimension(session, geom); 985 | data += sizeof(unsigned); 986 | 987 | if (!n) 988 | oracleError(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: empty line is not supported"); 989 | 990 | appendElemInfo(session, geom, numCoord(session, geom) + 1); /* start index + 1 */ 991 | appendElemInfo(session, geom, 2); /* SDO_ETYPE linestring */ 992 | appendElemInfo(session, geom, 1); /* SDO_INTERPRETATION straight line segments */ 993 | 994 | for (i=0; inum_elems / 3; 1006 | /* there is the number of rings, and, for each ring the number of points 1007 | * numRings%2 is there for padding 1008 | */ 1009 | return (numRings + 2 + numRings % 2) * sizeof(unsigned) 1010 | + sizeof(double) * geom->num_coords; 1011 | } 1012 | 1013 | const char * 1014 | setPolygon(oracleSession *session, ora_geometry *geom, const char *data) 1015 | { 1016 | unsigned r, i, numRings; 1017 | const unsigned dimension = sdoDimension(session, geom); 1018 | const char * ringSizeData; 1019 | 1020 | if (*((unsigned *)data) != POLYGONTYPE) 1021 | oracleError_i(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: expected polygon, got type %u", *((unsigned *)data)); 1022 | data += sizeof(unsigned); 1023 | 1024 | numRings = *((unsigned *)data); 1025 | data += sizeof(unsigned); 1026 | 1027 | if (!numRings) 1028 | oracleError(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: empty polygon is not supported"); 1029 | 1030 | ringSizeData = data; 1031 | data += (numRings+numRings%2)*sizeof(unsigned); 1032 | for (r=0; rnum_elems / 3; 1056 | const unsigned numC = geom->num_coords; 1057 | unsigned i; 1058 | dest = unsignedFill(POLYGONTYPE, dest); 1059 | 1060 | dest = unsignedFill(numRings, dest); 1061 | 1062 | for (i=0; ielem[i*3] - 1; 1065 | const unsigned coord_e = i+1 == numRings 1066 | ? numC 1067 | : geom->elem[(i+1)*3] - 1; 1068 | const unsigned numPoints = (coord_e - coord_b) / dimension; 1069 | dest = unsignedFill(numPoints, dest); 1070 | } 1071 | 1072 | /* padding */ 1073 | if ( numRings % 2 != 0 ) dest = unsignedFill(0, dest); 1074 | 1075 | for (i=0; icoord[i], dest); 1076 | 1077 | return dest; 1078 | } 1079 | 1080 | unsigned 1081 | ewkbMultiPointLen(oracleSession *session, ora_geometry *geom) 1082 | { 1083 | const unsigned numC = geom->num_coords; 1084 | const unsigned numPoints = numC / sdoDimension(session, geom); 1085 | return 2*sizeof(unsigned) + (2*sizeof(unsigned)*numPoints) + sizeof(double)*numC; 1086 | } 1087 | 1088 | char * 1089 | ewkbMultiPointFill(oracleSession *session, ora_geometry *geom, char * dest) 1090 | { 1091 | unsigned i; 1092 | const unsigned dim = sdoDimension(session, geom); 1093 | const unsigned numPoints = geom->num_coords / dim; 1094 | dest = unsignedFill(MULTIPOINTTYPE, dest); 1095 | dest = unsignedFill(numPoints, dest); 1096 | for (i=0; icoord[i*dim+j], dest); 1102 | } 1103 | 1104 | return dest; 1105 | } 1106 | 1107 | const char * 1108 | setMultiPoint(oracleSession *session, ora_geometry *geom, const char *data) 1109 | { 1110 | unsigned i, j, numPoints; 1111 | const unsigned dimension = sdoDimension(session, geom); 1112 | 1113 | if (*((unsigned *)data) != MULTIPOINTTYPE) 1114 | oracleError_i(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: expected multipoint, got type %u", *((unsigned *)data)); 1115 | data += sizeof(unsigned); 1116 | numPoints = *((unsigned *)data); 1117 | data += sizeof(unsigned); 1118 | 1119 | if (!numPoints) 1120 | oracleError(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: empty multipoint is not supported"); 1121 | 1122 | for (i=0; inum_elems / 3; 1146 | return 2 * sizeof(unsigned) + 2 * sizeof(unsigned) * numLines + sizeof(double) * geom->num_coords; 1147 | } 1148 | 1149 | char * 1150 | ewkbMultiLineFill(oracleSession *session, ora_geometry *geom, char * dest) 1151 | { 1152 | unsigned i; 1153 | const unsigned numC = geom->num_coords; 1154 | const unsigned dimension = sdoDimension(session, geom); 1155 | const unsigned numLines = geom->num_elems / 3; 1156 | dest = unsignedFill(MULTILINETYPE, dest); 1157 | dest = unsignedFill(numLines, dest); 1158 | for (i=0; ielem[i*3] - 1; 1162 | const unsigned coord_e = i+1 == numLines 1163 | ? numC 1164 | : geom->elem[(i+1)*3] - 1; 1165 | const unsigned numPoints = (coord_e - coord_b) / dimension; 1166 | dest = unsignedFill(LINETYPE, dest); 1167 | dest = unsignedFill(numPoints, dest); 1168 | for (j=coord_b; jcoord[j], dest); 1169 | } 1170 | 1171 | return dest; 1172 | } 1173 | 1174 | const char * 1175 | setMultiLine(oracleSession *session, ora_geometry *geom, const char *data) 1176 | { 1177 | unsigned r, numLines; 1178 | if (*((unsigned *)data) != MULTILINETYPE) 1179 | oracleError_i(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: expected multiline, got type %u", *((unsigned *)data)); 1180 | data += sizeof(unsigned); 1181 | numLines = *((unsigned *)data); 1182 | data += sizeof(unsigned); 1183 | 1184 | if (!numLines) 1185 | oracleError(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: empty multiline is not supported"); 1186 | 1187 | for (r=0; rnum_elems / 3; 1197 | unsigned numPolygon = 0; 1198 | unsigned i, j; 1199 | unsigned padding = 0; 1200 | 1201 | for (i = 0; ielem[i*3+1] == 1003 ; 1203 | 1204 | for (i=0, j=0; i < numPolygon; i++) 1205 | { 1206 | unsigned numRings = 1; 1207 | /* move j to the next ext ring, or the end */ 1208 | for (j++; j < totalNumRings && geom->elem[j*3+1] != 1003; j++, numRings++); 1209 | padding += numRings%2; 1210 | 1211 | } 1212 | 1213 | /* there is the type and the number of polygons, for each polygon the type 1214 | * and number of rings and 1215 | * for each ring the number of points and the padding 1216 | */ 1217 | return 2*sizeof(unsigned) + 1218 | + numPolygon*(2*sizeof(unsigned)) 1219 | + (totalNumRings + padding)*(sizeof(unsigned)) 1220 | + sizeof(double) * geom->num_coords; 1221 | } 1222 | 1223 | 1224 | char * 1225 | ewkbMultiPolygonFill(oracleSession *session, ora_geometry *geom, char * dest) 1226 | { 1227 | const unsigned dimension = sdoDimension(session, geom); 1228 | const unsigned numC = geom->num_coords; 1229 | const unsigned totalNumRings = geom->num_elems / 3; 1230 | unsigned numPolygon = 0; 1231 | unsigned i, j; 1232 | 1233 | for (i = 0; ielem[i*3+1] == 1003 ; 1235 | 1236 | dest = unsignedFill(MULTIPOLYGONTYPE, dest); 1237 | dest = unsignedFill(numPolygon, dest); 1238 | 1239 | for (i=0, j=0; i < numPolygon; i++) 1240 | { 1241 | unsigned end, k; 1242 | unsigned numRings = 1; 1243 | /* move j to the next ext ring, or the end */ 1244 | for (j++; j < totalNumRings && geom->elem[j*3+1] != 1003; j++, numRings++); 1245 | dest = unsignedFill(POLYGONTYPE, dest); 1246 | dest = unsignedFill(numRings, dest); 1247 | 1248 | /* 1249 | * Reset j to be on the exterior ring of the current polygon 1250 | * and output rings number of points. 1251 | */ 1252 | for (end = j, j -= numRings; jelem[j*3] - 1; 1255 | const unsigned coord_e = j+1 == totalNumRings 1256 | ? numC 1257 | : geom->elem[(j+1)*3] - 1; 1258 | const unsigned numPoints = (coord_e - coord_b) / dimension; 1259 | dest = unsignedFill(numPoints, dest); 1260 | } 1261 | 1262 | if (numRings%2) dest = unsignedFill(0, dest); /* padding */ 1263 | 1264 | for (end = j, j -= numRings; jelem[j*3] - 1; 1267 | const unsigned coord_e = j+1 == totalNumRings 1268 | ? numC 1269 | : geom->elem[(j+1)*3] - 1; 1270 | 1271 | for (k=coord_b; kcoord[k], dest); 1272 | } 1273 | } 1274 | return dest; 1275 | } 1276 | 1277 | const char * 1278 | setMultiPolygon(oracleSession *session, ora_geometry *geom, const char *data) 1279 | { 1280 | unsigned p, numPolygons; 1281 | 1282 | if (*((unsigned *)data) != MULTIPOLYGONTYPE) 1283 | oracleError_i(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: expected multipolygon, got type %u", *((unsigned *)data)); 1284 | data += sizeof(unsigned); 1285 | numPolygons = *((unsigned *)data); 1286 | data += sizeof(unsigned); 1287 | 1288 | if (!numPolygons) 1289 | oracleError(FDW_ERROR, "error converting geometry to SDO_GEOMETRY: empty multipolygon is not supported"); 1290 | 1291 | for (p=0; penvp->envhp, 1308 | session->envp->errhp, 1309 | (OCIColl *)(geom->geometry->sdo_ordinates), 1310 | &n), 1311 | session->envp->errhp) != OCI_SUCCESS) 1312 | oracleError_d(FDW_ERROR, "cannot get size of ordinate collection", oraMessage); 1313 | return n; 1314 | } 1315 | 1316 | /* 1317 | * coord 1318 | * Get the i'th element of the SDO_ORDINATES collection of "geom". 1319 | * This should only be called from unpack(). 1320 | */ 1321 | double 1322 | coord(oracleSession *session, ora_geometry *geom, unsigned i) 1323 | { 1324 | double coord; 1325 | boolean exists; 1326 | OCINumber *oci_number; 1327 | OCIInd *indicator; 1328 | 1329 | if (checkerr( 1330 | OCICollGetElem(session->envp->envhp, session->envp->errhp, 1331 | (OCIColl *)(geom->geometry->sdo_ordinates), 1332 | (sb4)i, 1333 | &exists, 1334 | (dvoid **)&oci_number, 1335 | (dvoid **)&indicator), 1336 | session->envp->errhp) != OCI_SUCCESS) 1337 | oracleError_d(FDW_ERROR, "error fetching element from ordinate collection", oraMessage); 1338 | if (! exists) 1339 | oracleError_i(FDW_ERROR, "element %u of ordinate collection does not exist", i); 1340 | if (*indicator == OCI_IND_NULL) 1341 | oracleError_i(FDW_ERROR, "element %u of ordinate collection is NULL", i); 1342 | /* convert the element to double */ 1343 | numberToDouble(session->envp->errhp, oci_number, &coord); 1344 | 1345 | return coord; 1346 | } 1347 | 1348 | /* 1349 | * numElemInfo 1350 | * Get the number of elements in the SDO_ELEM_INFO collection of "geom". 1351 | * This should only be called from unpack() and the set...() functions. 1352 | */ 1353 | unsigned 1354 | numElemInfo(oracleSession *session, ora_geometry *geom) 1355 | { 1356 | int n; 1357 | if (checkerr( 1358 | OCICollSize (session->envp->envhp, 1359 | session->envp->errhp, 1360 | (OCIColl *)(geom->geometry->sdo_elem_info), 1361 | &n), 1362 | session->envp->errhp) != OCI_SUCCESS) 1363 | oracleError_d(FDW_ERROR, "cannot get size of element info collection", oraMessage); 1364 | return n; 1365 | } 1366 | 1367 | /* 1368 | * elemInfo 1369 | * Get the i'th element of the SDO_ELEM_INFO collection of "geom". 1370 | * This should only be called from unpack(). 1371 | */ 1372 | unsigned 1373 | elemInfo(oracleSession *session, ora_geometry *geom, unsigned i) 1374 | { 1375 | unsigned info; 1376 | boolean exists; 1377 | OCINumber *oci_number; 1378 | OCIInd *indicator; 1379 | 1380 | if (checkerr( 1381 | OCICollGetElem(session->envp->envhp, session->envp->errhp, 1382 | (OCIColl *)(geom->geometry->sdo_elem_info), 1383 | (sb4)i, 1384 | &exists, 1385 | (dvoid **)&oci_number, 1386 | (dvoid **)&indicator), 1387 | session->envp->errhp) != OCI_SUCCESS) 1388 | oracleError_d(FDW_ERROR, "error fetching element from element info collection", oraMessage); 1389 | if (! exists) 1390 | oracleError_i(FDW_ERROR, "element %u of element info collection does not exist", i); 1391 | if (*indicator == OCI_IND_NULL) 1392 | oracleError_i(FDW_ERROR, "element %u of element info collection is NULL", i); 1393 | numberToUint(session->envp->errhp, oci_number, &info); 1394 | return info; 1395 | } 1396 | 1397 | /* 1398 | * unpack 1399 | * Unpack the data from the collections and store them in "geom". 1400 | * Also remove all the elements with SDO_ETYPE 0. 1401 | */ 1402 | void 1403 | unpack(oracleSession *session, ora_geometry *geom) 1404 | { 1405 | int elemCount, coordCount, elem_i, coord_i, elem_pos = 0, coord_pos = 0; 1406 | unsigned next_offset = 0; 1407 | 1408 | /* don't do anything for NULL SDO_ELEM_INFO and SDO_ORDINATES */ 1409 | if (geom->indicator->sdo_elem_info != OCI_IND_NOTNULL 1410 | && geom->indicator->sdo_ordinates != OCI_IND_NOTNULL) 1411 | return; 1412 | 1413 | /* both SDO_ELEM_INFO and SDO_ORDINATES must be NOT NULL */ 1414 | if (geom->indicator->sdo_elem_info != OCI_IND_NOTNULL 1415 | || geom->indicator->sdo_ordinates != OCI_IND_NOTNULL) 1416 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: SDO_ELEM_INFO and SDO_ORDINATES must either both be NULL"); 1417 | 1418 | elemCount = numElemInfo(session,geom); 1419 | coordCount = numCoord(session,geom); 1420 | 1421 | if (elemCount%3 != 0) 1422 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: size of SDO_ELEM_INFO must be a multiple of three"); 1423 | 1424 | /* this might be too big if some elements with etype 0 are deleted */ 1425 | geom->elem = oracleAlloc(elemCount * sizeof(unsigned)); 1426 | geom->coord = oracleAlloc(coordCount * sizeof(double)); 1427 | 1428 | for (elem_i = 0; elem_i + 1 < elemCount; elem_i +=3) 1429 | { 1430 | unsigned offset, etype, interpretation; 1431 | 1432 | if (next_offset == 0) 1433 | offset = elemInfo(session, geom, elem_i); 1434 | else 1435 | offset = next_offset; 1436 | etype = elemInfo(session, geom, elem_i + 1); 1437 | interpretation = elemInfo(session, geom, elem_i + 2); 1438 | if (elem_i + 4 < elemCount) 1439 | next_offset = elemInfo(session, geom, elem_i + 3); 1440 | else 1441 | next_offset = coordCount + 1; 1442 | 1443 | if (etype != 0) 1444 | { 1445 | /* 1446 | * Copy the three ELEM_INFO entries and their ordinates. 1447 | */ 1448 | 1449 | /* adjust offset */ 1450 | geom->elem[elem_pos] = coord_pos + 1; 1451 | geom->elem[elem_pos + 1] = etype; 1452 | geom->elem[elem_pos + 2] = interpretation; 1453 | 1454 | elem_pos += 3; 1455 | 1456 | /* copy ordinates for this entry */ 1457 | for (coord_i=offset - 1; coord_i < next_offset - 1; ++coord_i) 1458 | geom->coord[coord_pos++] = coord(session, geom, coord_i); 1459 | } 1460 | } 1461 | 1462 | geom->num_elems = elem_pos; 1463 | geom->num_coords = coord_pos; 1464 | 1465 | if (elem_pos == 0) 1466 | oracleError(FDW_ERROR, "error converting SDO_GEOMETRY to geometry: SDO_ELEM_INFO must contain element with non-zero ETYPE"); 1467 | } 1468 | 1469 | /* 1470 | * freeUnpacked 1471 | * Free the memory allocated in "unpack" and clear the settings in "geom". 1472 | */ 1473 | void 1474 | freeUnpacked(oracleSession *session, ora_geometry *geom) 1475 | { 1476 | if (geom->elem != NULL) 1477 | oracleFree(geom->elem); 1478 | if (geom->coord != NULL) 1479 | oracleFree(geom->coord); 1480 | 1481 | geom->num_elems = -1; 1482 | geom->elem = NULL; 1483 | geom->num_coords = -1; 1484 | geom->coord = NULL; 1485 | } 1486 | 1487 | /* 1488 | * checkerr 1489 | * Call OCIErrorGet to get error message and error code. 1490 | */ 1491 | sword 1492 | checkerr(sword status, OCIError *handle) 1493 | { 1494 | unsigned length; 1495 | oraMessage[0] = '\0'; 1496 | 1497 | if (status == OCI_SUCCESS_WITH_INFO || status == OCI_ERROR) 1498 | { 1499 | OCIErrorGet(handle, (ub4)1, NULL, &err_code, 1500 | (text *)oraMessage, (ub4)ERRBUFSIZE, OCI_HTYPE_ERROR); 1501 | length = strlen(oraMessage); 1502 | if (length > 0 && oraMessage[length-1] == '\n') 1503 | oraMessage[length-1] = '\0'; 1504 | } 1505 | 1506 | if (status == OCI_SUCCESS_WITH_INFO) 1507 | status = OCI_SUCCESS; 1508 | 1509 | if (status == OCI_NO_DATA) 1510 | { 1511 | strcpy(oraMessage, "ORA-00100: no data found"); 1512 | err_code = (sb4)100; 1513 | } 1514 | 1515 | return status; 1516 | } 1517 | -------------------------------------------------------------------------------- /sql/oracle_fdw.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * Install the extension and define the tables. 3 | * All the foreign tables defined refer to the same Oracle table. 4 | */ 5 | 6 | SET client_min_messages = WARNING; 7 | 8 | CREATE EXTENSION oracle_fdw; 9 | 10 | -- TWO_TASK or ORACLE_HOME and ORACLE_SID must be set in the server's environment for this to work 11 | CREATE SERVER oracle FOREIGN DATA WRAPPER oracle_fdw OPTIONS (dbserver '', isolation_level 'read_committed', nchar 'true', set_timezone 'true'); 12 | 13 | CREATE USER MAPPING FOR CURRENT_ROLE SERVER oracle OPTIONS (user 'SCOTT', password 'tiger'); 14 | 15 | -- drop the Oracle objects if they exist 16 | DO 17 | $$BEGIN 18 | SELECT oracle_execute('oracle', 'DROP VIEW scott.ttv'); 19 | EXCEPTION 20 | WHEN OTHERS THEN 21 | NULL; 22 | END;$$; 23 | 24 | DO 25 | $$BEGIN 26 | SELECT oracle_execute('oracle', 'DROP TABLE scott.typetest1 PURGE'); 27 | EXCEPTION 28 | WHEN OTHERS THEN 29 | NULL; 30 | END;$$; 31 | 32 | DO 33 | $$BEGIN 34 | SELECT oracle_execute('oracle', 'DROP MATERIALIZED VIEW scott.mattest2'); 35 | EXCEPTION 36 | WHEN OTHERS THEN 37 | NULL; 38 | END;$$; 39 | 40 | DO 41 | $$BEGIN 42 | SELECT oracle_execute('oracle', 'DROP TABLE scott.typetest2 PURGE'); 43 | EXCEPTION 44 | WHEN OTHERS THEN 45 | NULL; 46 | END;$$; 47 | 48 | DO 49 | $$BEGIN 50 | SELECT oracle_execute('oracle', 'DROP TABLE scott.gis PURGE'); 51 | EXCEPTION 52 | WHEN OTHERS THEN 53 | NULL; 54 | END;$$; 55 | 56 | SELECT oracle_execute( 57 | 'oracle', 58 | E'CREATE TABLE scott.typetest1 (\n' 59 | ' id NUMBER(5)\n' 60 | ' CONSTRAINT typetest1_pkey PRIMARY KEY,\n' 61 | ' c CHAR(10 CHAR),\n' 62 | ' nc NCHAR(10),\n' 63 | ' vc VARCHAR2(10 CHAR),\n' 64 | ' nvc NVARCHAR2(10),\n' 65 | ' lc CLOB,\n' 66 | ' lnc NCLOB,\n' 67 | ' r RAW(10),\n' 68 | ' u RAW(16),\n' 69 | ' lb BLOB,\n' 70 | ' lr LONG RAW,\n' 71 | ' b NUMBER(1),\n' 72 | ' num NUMBER(7,5),\n' 73 | ' fl BINARY_FLOAT,\n' 74 | ' db BINARY_DOUBLE,\n' 75 | ' d DATE,\n' 76 | ' ts TIMESTAMP WITH TIME ZONE,\n' 77 | ' ids INTERVAL DAY TO SECOND,\n' 78 | ' iym INTERVAL YEAR TO MONTH\n' 79 | ') SEGMENT CREATION IMMEDIATE' 80 | ); 81 | 82 | SELECT oracle_execute( 83 | 'oracle', 84 | E'CREATE VIEW scott.ttv AS\n' 85 | 'SELECT id, vc FROM scott.typetest1' 86 | ); 87 | 88 | SELECT oracle_execute( 89 | 'oracle', 90 | E'CREATE TABLE scott.typetest2 (\n' 91 | ' id NUMBER(5)\n' 92 | ' CONSTRAINT typetest2_pkey PRIMARY KEY,\n' 93 | ' ts1 TIMESTAMP WITH LOCAL TIME ZONE,\n' 94 | ' ts2 TIMESTAMP WITH LOCAL TIME ZONE,\n' 95 | ' ts3 TIMESTAMP WITH LOCAL TIME ZONE\n' 96 | ') SEGMENT CREATION IMMEDIATE' 97 | ); 98 | 99 | SELECT oracle_execute( 100 | 'oracle', 101 | E'CREATE TABLE scott.gis (\n' 102 | ' id NUMBER(5) PRIMARY KEY,\n' 103 | ' g MDSYS.SDO_GEOMETRY\n' 104 | ') SEGMENT CREATION IMMEDIATE' 105 | ); 106 | 107 | -- gather statistics 108 | SELECT oracle_execute( 109 | 'oracle', 110 | E'BEGIN\n' 111 | ' DBMS_STATS.GATHER_TABLE_STATS (''SCOTT'', ''TYPETEST1'', NULL, 100);\n' 112 | 'END;' 113 | ); 114 | 115 | SELECT oracle_execute( 116 | 'oracle', 117 | E'BEGIN\n' 118 | ' DBMS_STATS.GATHER_TABLE_STATS (''SCOTT'', ''TYPETEST2'', NULL, 100);\n' 119 | 'END;' 120 | ); 121 | 122 | SELECT oracle_execute( 123 | 'oracle', 124 | E'BEGIN\n' 125 | ' DBMS_STATS.GATHER_TABLE_STATS (''SCOTT'', ''GIS'', NULL, 100);\n' 126 | 'END;' 127 | ); 128 | 129 | -- initial data for typetest2 130 | SELECT oracle_execute( 131 | 'oracle', 132 | E'INSERT INTO scott.typetest2 (id, ts1, ts2, ts3) VALUES (\n' 133 | ' 1,\n' 134 | ' FROM_TZ(CAST (''2002-08-01 00:00:00 AD'' AS timestamp), ''UTC''),\n' 135 | ' FROM_TZ(CAST (''2002-08-01 00:00:00 AD'' AS timestamp), ''UTC''),\n' 136 | ' FROM_TZ(CAST (''2002-08-01 00:00:00 AD'' AS timestamp), ''UTC'')\n' 137 | ')' 138 | ); 139 | 140 | -- a materialized view 141 | SELECT oracle_execute( 142 | 'oracle', 143 | E'CREATE MATERIALIZED VIEW scott.mattest2 REFRESH COMPLETE AS\n' 144 | ' SELECT id, ts1, ts2, ts3 FROM scott.typetest2' 145 | ); 146 | 147 | -- create the foreign tables 148 | CREATE FOREIGN TABLE typetest1 ( 149 | id integer OPTIONS (key 'yes') NOT NULL, 150 | q double precision, 151 | c character(10), 152 | nc character(10), 153 | vc character varying(10), 154 | nvc character varying(10), 155 | lc text, 156 | lnc text, 157 | r bytea, 158 | u uuid, 159 | lb bytea, 160 | lr bytea, 161 | b boolean, 162 | num numeric(7,5), 163 | fl float, 164 | db double precision, 165 | d date, 166 | ts timestamp with time zone, 167 | ids interval, 168 | iym interval 169 | ) SERVER oracle OPTIONS (table 'TYPETEST1', prefetch '2', lob_prefetch '5000'); 170 | ALTER FOREIGN TABLE typetest1 DROP q; 171 | 172 | -- a table that is missing some fields 173 | CREATE FOREIGN TABLE shorty ( 174 | id integer OPTIONS (key 'yes') NOT NULL, 175 | c character(10) 176 | ) SERVER oracle OPTIONS (table 'TYPETEST1'); 177 | 178 | -- a table that has some extra fields 179 | CREATE FOREIGN TABLE longy ( 180 | id integer OPTIONS (key 'yes') NOT NULL, 181 | c character(10), 182 | nc character(10), 183 | vc character varying(10), 184 | nvc character varying(10), 185 | lc text, 186 | lnc text, 187 | r bytea, 188 | u uuid, 189 | lb bytea, 190 | lr bytea, 191 | b boolean, 192 | num numeric(7,5), 193 | fl float, 194 | db double precision, 195 | d date, 196 | ts timestamp with time zone, 197 | ids interval, 198 | iym interval, 199 | x integer 200 | ) SERVER oracle OPTIONS (table 'TYPETEST1'); 201 | 202 | CREATE FOREIGN TABLE typetest2 ( 203 | id integer OPTIONS (key 'yes') NOT NULL, 204 | ts1 timestamp with time zone, 205 | ts2 timestamp without time zone, 206 | ts3 date 207 | ) SERVER oracle OPTIONS (table 'TYPETEST2'); 208 | 209 | /* 210 | * INSERT some rows into "typetest1". 211 | */ 212 | 213 | -- will fail with a read-only transaction 214 | ALTER SERVER oracle OPTIONS (SET isolation_level 'read_only'); 215 | SELECT oracle_close_connections(); 216 | DELETE FROM typetest1; 217 | 218 | -- use the default SERIALIZABLE isolation level from now on 219 | ALTER SERVER oracle OPTIONS (DROP isolation_level); 220 | SELECT oracle_close_connections(); 221 | DELETE FROM typetest1; 222 | 223 | INSERT INTO typetest1 (id, c, nc, vc, nvc, lc, lnc, r, u, lb, lr, b, num, fl, db, d, ts, ids, iym) VALUES ( 224 | 1, 225 | 'fixed char', 226 | 'nat''l char', 227 | 'varlena', 228 | 'nat''l var', 229 | 'character large object', 230 | 'character national large object', 231 | bytea('\xDEADBEEF'), 232 | uuid('055e26fa-f1d8-771f-e053-1645990add93'), 233 | bytea('\xDEADBEEF'), 234 | bytea('\xDEADBEEF'), 235 | TRUE, 236 | 3.14159, 237 | 3.14159, 238 | 3.14159, 239 | '1968-10-20', 240 | '2009-01-26 15:02:54.893532 PST', 241 | '1 day 2 hours 30 seconds 1 microsecond', 242 | '-6 months' 243 | ); 244 | 245 | -- change the "boolean" in Oracle to "2" 246 | SELECT oracle_execute('oracle', 'UPDATE typetest1 SET b = 2 WHERE id = 1'); 247 | 248 | INSERT INTO shorty (id, c) VALUES (2, NULL); 249 | 250 | INSERT INTO typetest1 (id, c, nc, vc, nvc, lc, lnc, r, u, lb, lr, b, num, fl, db, d, ts, ids, iym) VALUES ( 251 | 3, 252 | E'a\u001B\u0007\u000D\u007Fb', 253 | E'a\u001B\u0007\u000D\u007Fb', 254 | E'a\u001B\u0007\u000D\u007Fb', 255 | E'a\u001B\u0007\u000D\u007Fb', 256 | E'a\u001B\u0007\u000D\u007Fb ABC' || repeat('X', 9000), 257 | E'a\u001B\u0007\u000D\u007Fb ABC' || repeat('X', 9000), 258 | bytea('\xDEADF00D'), 259 | uuid('055f3b32-a02c-4532-e053-1645990a6db2'), 260 | bytea('\xDEADF00DDEADF00DDEADF00D'), 261 | bytea('\xDEADF00DDEADF00DDEADF00D'), 262 | FALSE, 263 | -2.71828, 264 | -2.71828, 265 | -2.71828, 266 | '0044-03-15 BC', 267 | '0044-03-15 12:00:00 BC', 268 | '-2 days -12 hours -30 minutes', 269 | '-2 years -6 months' 270 | ); 271 | 272 | INSERT INTO typetest1 (id, c, nc, vc, nvc, lc, lnc, r, u, lb, lr, b, num, fl, db, d, ts, ids, iym) VALUES ( 273 | 4, 274 | 'short', 275 | 'short', 276 | 'short', 277 | 'short', 278 | 'short', 279 | 'short', 280 | bytea('\xDEADF00D'), 281 | uuid('0560ee34-2ef9-1137-e053-1645990ac874'), 282 | bytea('\xDEADF00D'), 283 | bytea('\xDEADF00D'), 284 | NULL, 285 | 0, 286 | 0, 287 | 0, 288 | NULL, 289 | NULL, 290 | '23:59:59.999999', 291 | '3 years' 292 | ); 293 | 294 | -- try inserting an empty string into a CLOB (will become NULL) 295 | BEGIN; 296 | INSERT INTO typetest1 (id, lc) VALUES (5, ''); 297 | SELECT lc IS NULL FROM typetest1 WHERE id = 5; 298 | ROLLBACK; 299 | 300 | /* 301 | * Test SELECT, UPDATE ... RETURNING, DELETE and transactions. 302 | */ 303 | 304 | -- simple SELECT 305 | SELECT id, c, nc, vc, nvc, lc, r, u, lb, lr, b, num, fl, db, d, ts, ids, iym, x FROM longy ORDER BY id; 306 | -- mass UPDATE 307 | WITH upd (id, c, lb, d, ts) AS 308 | (UPDATE longy SET c = substr(c, 1, 9) || 'u', 309 | lb = lb || bytea('\x00'), 310 | lr = lr || bytea('\x00'), 311 | d = d + 1, 312 | ts = ts + '1 day' 313 | WHERE id < 3 RETURNING id + 1, c, lb, d, ts) 314 | SELECT * FROM upd ORDER BY id; 315 | -- transactions 316 | BEGIN; 317 | DELETE FROM shorty WHERE id = 2; 318 | SAVEPOINT one; 319 | -- will cause an error 320 | INSERT INTO shorty (id, c) VALUES (1, 'c'); 321 | ROLLBACK TO one; 322 | INSERT INTO shorty (id, c) VALUES (2, 'c'); 323 | ROLLBACK TO one; 324 | COMMIT; 325 | -- see if the correct data are in the table 326 | SELECT id, c FROM typetest1 ORDER BY id; 327 | -- try to update the nonexistant column (should cause an error) 328 | UPDATE longy SET x = NULL WHERE id = 1; 329 | -- check that UPDATES work with "date" in Oracle and "timestamp" in PostgreSQL 330 | BEGIN; 331 | ALTER FOREIGN TABLE typetest1 ALTER COLUMN d TYPE timestamp(0) without time zone; 332 | UPDATE typetest1 SET d = '1968-10-10 12:00:00' WHERE id = 1 RETURNING d; 333 | ROLLBACK; 334 | -- test if "IN" or "= ANY" expressions are pushed down correctly 335 | SELECT vc FROM typetest1 WHERE id IN (1, 3, 4) ORDER BY id; 336 | EXPLAIN (COSTS off) SELECT vc FROM typetest1 WHERE id IN (1, 3, 4) ORDER BY id; 337 | SELECT id FROM typetest1 WHERE vc = ANY (ARRAY['short', (SELECT 'varlena'::varchar)]) ORDER BY id; 338 | EXPLAIN (COSTS off) SELECT id FROM typetest1 WHERE vc = ANY (ARRAY['short', (SELECT 'varlena'::varchar)]) ORDER BY id; 339 | -- test NULLIF pushdown 340 | SELECT id FROM typetest1 WHERE nullif(id, 1) IS NULL ORDER BY id; 341 | EXPLAIN (COSTS off) SELECT id FROM typetest1 WHERE nullif(id, 1) IS NULL ORDER BY id; 342 | -- test coalesce() pushdown 343 | SELECT id FROM typetest1 WHERE coalesce(d, current_date) = current_date ORDER BY id; 344 | EXPLAIN (COSTS off) SELECT id FROM typetest1 WHERE coalesce(d, current_date) = current_date ORDER BY id; 345 | -- test modifications that need no foreign scan scan (bug #295) 346 | DELETE FROM typetest1 WHERE FALSE; 347 | UPDATE shorty SET c = NULL WHERE FALSE RETURNING *; 348 | -- test deparsing of ScalarArrayOpExpr where the RHS has different element type than the LHS 349 | SELECT id FROM typetest1 WHERE vc = ANY ('{zzzzz}'::name[]); 350 | -- test whole-row references with RETURNING (bug #568) 351 | INSERT INTO shorty (id, c) VALUES (5, 'return me') RETURNING shorty; 352 | UPDATE shorty SET c = 'changed' WHERE id = 5 RETURNING shorty; 353 | DELETE FROM shorty WHERE id = 5 RETURNING shorty; 354 | -- test generated columns (bug #567) 355 | CREATE FOREIGN TABLE gen ( 356 | id integer OPTIONS (key 'on') NOT NULL, 357 | c character(10) GENERATED ALWAYS AS ('nr ' || id::text) STORED 358 | ) SERVER oracle OPTIONS (schema 'SCOTT', table 'TYPETEST1'); 359 | INSERT INTO gen (id) VALUES (5); 360 | SELECT id, c FROM gen WHERE id = 5; 361 | UPDATE gen SET id = 6 WHERE id = 5; 362 | SELECT id, c FROM gen WHERE id = 6; 363 | DELETE FROM gen WHERE id = 6; 364 | DROP FOREIGN TABLE gen; 365 | -- test for "ctid" in the WHERE clause (should fail) 366 | SELECT id FROM typetest1 WHERE ctid = '(0, 1)'; 367 | 368 | /* 369 | * Test "strip_zeros" column option. 370 | */ 371 | 372 | SELECT oracle_execute( 373 | 'oracle', 374 | 'INSERT INTO typetest1 (id, vc) VALUES (5, ''has'' || chr(0) || ''zeros'')' 375 | ); 376 | 377 | SELECT vc FROM typetest1 WHERE id = 5; -- should fail 378 | ALTER FOREIGN TABLE typetest1 ALTER vc OPTIONS (ADD strip_zeros 'yes'); 379 | SELECT vc FROM typetest1 WHERE id = 5; -- should work 380 | ALTER FOREIGN TABLE typetest1 ALTER vc OPTIONS (DROP strip_zeros); 381 | 382 | DELETE FROM typetest1 WHERE id = 5; 383 | 384 | /* 385 | * Test EXPLAIN support. 386 | */ 387 | 388 | EXPLAIN (COSTS off) UPDATE typetest1 SET lc = current_timestamp WHERE id < 4 RETURNING id + 1; 389 | EXPLAIN (VERBOSE on, COSTS off) SELECT * FROM shorty; 390 | -- this should fetch all columns from the foreign table 391 | EXPLAIN (COSTS off) SELECT typetest1 FROM typetest1; 392 | 393 | /* 394 | * Test parameters. 395 | */ 396 | 397 | PREPARE stmt(integer, date, timestamp, uuid) AS SELECT d FROM typetest1 WHERE id = $1 AND d < $2 AND ts < $3 AND u = $4; 398 | -- six executions to switch to generic plan 399 | EXECUTE stmt(1, '2011-03-09', '2011-03-09 05:00:00', '055e26fa-f1d8-771f-e053-1645990add93'); 400 | EXECUTE stmt(1, '2011-03-09', '2011-03-09 05:00:00', '055e26fa-f1d8-771f-e053-1645990add93'); 401 | EXECUTE stmt(1, '2011-03-09', '2011-03-09 05:00:00', '055e26fa-f1d8-771f-e053-1645990add93'); 402 | EXECUTE stmt(1, '2011-03-09', '2011-03-09 05:00:00', '055e26fa-f1d8-771f-e053-1645990add93'); 403 | EXECUTE stmt(1, '2011-03-09', '2011-03-09 05:00:00', '055e26fa-f1d8-771f-e053-1645990add93'); 404 | EXPLAIN (COSTS off) EXECUTE stmt(1, '2011-03-09', '2011-03-09 05:00:00', '055e26fa-f1d8-771f-e053-1645990add93'); 405 | EXECUTE stmt(1, '2011-03-09', '2011-03-09 05:00:00', '055e26fa-f1d8-771f-e053-1645990add93'); 406 | DEALLOCATE stmt; 407 | -- test NULL parameters 408 | SELECT id FROM typetest1 WHERE vc = (SELECT NULL::text); 409 | 410 | /* 411 | * Test current_timestamp. 412 | */ 413 | SELECT id FROM typetest1 414 | WHERE d < current_date 415 | AND ts < now() 416 | AND ts < current_timestamp 417 | AND ts < 'now'::timestamp 418 | ORDER BY id; 419 | 420 | /* 421 | * Test foreign table based on SELECT statement. 422 | */ 423 | 424 | CREATE FOREIGN TABLE qtest ( 425 | id integer OPTIONS (key 'yes') NOT NULL, 426 | vc character varying(10), 427 | num numeric(7,5) 428 | ) SERVER oracle OPTIONS (table '(SELECT id, vc, num FROM typetest1)'); 429 | 430 | -- INSERT works with simple "view" 431 | INSERT INTO qtest (id, vc, num) VALUES (5, 'via query', -12.5); 432 | 433 | ALTER FOREIGN TABLE qtest OPTIONS (SET table '(SELECT id, SUBSTR(vc, 1, 3), num FROM typetest1)'); 434 | 435 | -- SELECT and DELETE should also work with derived columns 436 | SELECT * FROM qtest ORDER BY id; 437 | DELETE FROM qtest WHERE id = 5; 438 | 439 | /* 440 | * Test COPY 441 | */ 442 | 443 | BEGIN; 444 | COPY typetest1 FROM STDIN; 445 | 666 cöpy variation dynamo ünicode Not very long n'Clobber DEADF00D 9a0cf1eb-02e2-4b1f-bbe0-449fa4a99969 \\x01020304 \\xFFFF \N 0.11111 0.43211 0.01010 2100-01-29 2050-04-01 19:30:00 12 hours 0 years 446 | 777 fdjkl r89809rew ^ß[]#~ \N Das also ist des Pudels Kern. Foo 00 fe288446-05f6-4074-9e9e-6ee41af7b377 \\x00 \\x00 FALSE 10 1002 1003 2019-05-01 2019-05-01 0:00:00 0 seconds 1 year 447 | \. 448 | ROLLBACK; 449 | 450 | /* 451 | * Test foreign table as a partition. 452 | */ 453 | 454 | CREATE TABLE party (LIKE typetest1) PARTITION BY RANGE (id); 455 | CREATE TABLE defpart PARTITION OF party DEFAULT; 456 | ALTER TABLE party ATTACH PARTITION typetest1 FOR VALUES FROM (1) TO (MAXVALUE); 457 | BEGIN; 458 | COPY party FROM STDIN; 459 | 666 cöpy variation dynamo ünicode Not very long n'Clobber DEADF00D 9a0cf1eb-02e2-4b1f-bbe0-449fa4a99969 \\x01020304 \\xFFFF \N 0.11111 0.43211 0.01010 2100-01-29 2050-04-01 19:30:00 12 hours 0 years 460 | 777 fdjkl r89809rew ^ß[]#~ \N Das also ist des Pudels Kern. Foo 00 fe288446-05f6-4074-9e9e-6ee41af7b377 \\x00 \\x00 FALSE 10 1002 1003 2019-05-01 2019-05-01 0:00:00 0 seconds 1 year 461 | \. 462 | INSERT INTO party (id, lc, lr, lb) 463 | VALUES (12, 'very long character', '\x0001020304', '\xFFFEFDFC'); 464 | SELECT id, lr, lb, c FROM typetest1 ORDER BY id; 465 | ROLLBACK; 466 | 467 | BEGIN; 468 | CREATE TABLE shortpart ( 469 | id integer NOT NULL, 470 | c character(10) 471 | ) PARTITION BY LIST (id); 472 | ALTER TABLE shortpart ATTACH PARTITION shorty FOR VALUES IN (1, 2, 3, 4, 5, 6, 7, 8, 9); 473 | INSERT INTO shortpart (id, c) VALUES (6, 'returnme') RETURNING *; 474 | ROLLBACK; 475 | 476 | /* 477 | * Test triggers on foreign tables. 478 | */ 479 | 480 | -- trigger function 481 | CREATE FUNCTION shorttrig() RETURNS trigger LANGUAGE plpgsql AS 482 | $$BEGIN 483 | IF TG_OP IN ('UPDATE', 'DELETE') THEN 484 | RAISE WARNING 'trigger % % OLD row: id = %, c = %', TG_WHEN, TG_OP, OLD.id, OLD.c; 485 | END IF; 486 | IF TG_OP IN ('INSERT', 'UPDATE') THEN 487 | RAISE WARNING 'trigger % % NEW row: id = %, c = %', TG_WHEN, TG_OP, NEW.id, NEW.c; 488 | END IF; 489 | 490 | NEW.c := 'modified'; 491 | 492 | RETURN NEW; 493 | END;$$; 494 | 495 | -- test BEFORE trigger 496 | CREATE TRIGGER shorttrig BEFORE UPDATE ON shorty FOR EACH ROW EXECUTE PROCEDURE shorttrig(); 497 | BEGIN; 498 | UPDATE shorty SET id = id + 1 WHERE id = 4 RETURNING c; 499 | ROLLBACK; 500 | 501 | -- test AFTER trigger 502 | DROP TRIGGER shorttrig ON shorty; 503 | CREATE TRIGGER shorttrig AFTER UPDATE ON shorty FOR EACH ROW EXECUTE PROCEDURE shorttrig(); 504 | BEGIN; 505 | UPDATE shorty SET id = id + 1 WHERE id = 4; 506 | ROLLBACK; 507 | 508 | -- test AFTER INSERT trigger with COPY 509 | DROP TRIGGER shorttrig ON shorty; 510 | CREATE TRIGGER shorttrig AFTER INSERT ON shorty FOR EACH ROW EXECUTE PROCEDURE shorttrig(); 511 | BEGIN; 512 | COPY shorty FROM STDIN; 513 | 42 hammer 514 | 753 rom 515 | 0 \N 516 | \. 517 | ROLLBACK; 518 | 519 | /* 520 | * Test ORDER BY pushdown. 521 | */ 522 | 523 | -- don't push down string data types 524 | EXPLAIN (COSTS off) SELECT id FROM typetest1 ORDER BY id, vc; 525 | -- push down complicated expressions 526 | EXPLAIN (COSTS off) SELECT id FROM typetest1 ORDER BY length(vc), CASE WHEN vc IS NULL THEN 0 ELSE 1 END, ts DESC NULLS FIRST FOR UPDATE; 527 | SELECT id FROM typetest1 ORDER BY length(vc), CASE WHEN vc IS NULL THEN 0 ELSE 1 END, ts DESC NULLS FIRST FOR UPDATE; 528 | 529 | /* 530 | * Test that incorrect type mapping throws an error. 531 | */ 532 | 533 | -- create table with bad type matches 534 | CREATE FOREIGN TABLE badtypes ( 535 | id integer OPTIONS (key 'yes') NOT NULL, 536 | c xml, 537 | nc xml 538 | ) SERVER oracle OPTIONS (table 'TYPETEST1'); 539 | -- should fail for column "nc", as "c" is not used 540 | SELECT id, nc FROM badtypes WHERE id = 1; 541 | -- this will fail for inserting a NULL in column "c" 542 | INSERT INTO badtypes (id, nc) VALUES (42, XML ''); 543 | -- remove foreign table 544 | DROP FOREIGN TABLE badtypes; 545 | 546 | /* 547 | * Test subplans (initplans) 548 | */ 549 | 550 | -- testcase for bug #364 551 | SELECT id FROM typetest1 552 | WHERE vc NOT IN (SELECT * FROM (VALUES ('short'), ('other')) AS q) 553 | ORDER BY id; 554 | 555 | /* 556 | * Test type coerced array parameters (bug #452) 557 | */ 558 | 559 | PREPARE stmt(varchar[]) AS SELECT id FROM typetest1 WHERE vc = ANY ($1); 560 | EXECUTE stmt('{varlena,nonsense}'); 561 | EXECUTE stmt('{varlena,nonsense}'); 562 | EXECUTE stmt('{varlena,nonsense}'); 563 | EXECUTE stmt('{varlena,nonsense}'); 564 | EXECUTE stmt('{varlena,nonsense}'); 565 | EXECUTE stmt('{varlena,nonsense}'); 566 | DEALLOCATE stmt; 567 | 568 | 569 | /* test ANALYZE */ 570 | 571 | ANALYZE typetest1; 572 | ANALYZE longy; 573 | -- bug reported by Jan 574 | ANALYZE shorty; 575 | 576 | /* test if views and SECURITY DEFINER functions use the correct user mapping */ 577 | 578 | CREATE ROLE duff LOGIN; 579 | GRANT SELECT ON typetest1 TO PUBLIC; 580 | 581 | CREATE VIEW v_typetest1 AS SELECT id FROM typetest1; 582 | GRANT SELECT ON v_typetest1 TO PUBLIC; 583 | 584 | CREATE VIEW v_join AS 585 | SELECT id, a.vc, b.c 586 | FROM typetest1 AS a 587 | JOIN typetest1 AS b USING (id); 588 | GRANT SELECT ON v_join TO PUBLIC; 589 | 590 | CREATE FUNCTION f_typetest1() RETURNS TABLE (id integer) 591 | LANGUAGE sql SECURITY DEFINER AS 592 | 'SELECT id FROM public.typetest1'; 593 | 594 | SET SESSION AUTHORIZATION duff; 595 | -- this should fail 596 | SELECT id FROM typetest1 ORDER BY id; 597 | -- these should succeed 598 | SELECT id FROM v_typetest1 ORDER BY id; 599 | SELECT c FROM v_join WHERE vc = 'short'; 600 | SELECT id FROM f_typetest1() ORDER BY id; 601 | -- clean up 602 | RESET SESSION AUTHORIZATION; 603 | DROP ROLE duff; 604 | 605 | /* test "current_timestamp" and "current_date" pushdown */ 606 | 607 | EXPLAIN (COSTS off) 608 | SELECT id FROM typetest1 WHERE ts = current_timestamp; 609 | SELECT id FROM typetest1 WHERE ts = current_timestamp; 610 | EXPLAIN (COSTS off) 611 | SELECT id FROM typetest1 WHERE d = current_date; 612 | SELECT id FROM typetest1 WHERE d = current_date; 613 | 614 | /* test TIMESTAMP WITH LOCAL TIME ZONE */ 615 | 616 | INSERT INTO typetest2 (id, ts1, ts2, ts3) VALUES ( 617 | 2, 618 | '2020-12-31 00:00:00 UTC', 619 | '2020-12-31 00:00:00', 620 | '2020-12-31' 621 | ); 622 | SELECT * FROM typetest2 ORDER BY id; 623 | -- we need to re-establish the connection after changing "timezone" 624 | SELECT oracle_close_connections(); 625 | BEGIN; 626 | SET LOCAL timezone = 'Asia/Kolkata'; 627 | INSERT INTO typetest2 (id, ts1, ts2, ts3) VALUES ( 628 | 3, 629 | '2020-12-31 00:00:00 UTC', 630 | '2020-12-31 00:00:00', 631 | '2020-12-31' 632 | ); 633 | SELECT * FROM typetest2 ORDER BY id; 634 | COMMIT; 635 | -- we need to re-establish the connection after changing "timezone" 636 | SELECT oracle_close_connections(); 637 | -------------------------------------------------------------------------------- /sql/oracle_gis.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * Define the PostGIS extension and create a foreign table. 3 | */ 4 | 5 | CREATE EXTENSION postgis; 6 | -- reconnect so that oracle_fdw recognizes PostGIS 7 | \c 8 | SET client_min_messages = WARNING; 9 | -- Table with a PostGIS geometry 10 | CREATE FOREIGN TABLE gis ( 11 | id integer OPTIONS (key 'on') NOT NULL, 12 | g geometry 13 | ) SERVER oracle OPTIONS (table 'GIS'); 14 | 15 | /* 16 | * Empty the table and INSERT some data. 17 | */ 18 | 19 | -- empty table 20 | DELETE FROM gis; 21 | -- INSERT a couple of rows 22 | INSERT INTO gis (id, g) VALUES 23 | (1, 'SRID=8307;POINT(16.4891 48.1754)'), 24 | (2, 'SRID=0;LINESTRING(1552410.48 6720732.7,1552408.69 6720731.97)'), 25 | (3, 'SRID=8307;POINT Z (1.5 2.6 3.7)'), 26 | (4, NULL), 27 | (5, 'SRID=8307;MULTIPOLYGON(((50 168,50 160,55 160,55 168,50 168),(51 167,54 167,54 161,51 161,51 162,52 163,51 164,51 165,51 166,51 167)),((52 166,52 162,53 162,53 166,52 166)))'), 28 | (6, 'SRID=8307;POLYGON((35 10,45 45,15 40,10 20,35 10),(20 30,35 35,30 20,20 30))'), 29 | (7, 'SRID=8307;MULTILINESTRING((10 10,20 20,10 40),(40 40,30 30,40 20,30 10))'), 30 | (8, 'SRID=8307;MULTIPOLYGON(((40 40,20 45,45 30,40 40)),((20 35,10 30,10 10,30 5,45 20,20 35),(30 20,20 15,20 25,30 20)))'), 31 | (9, 'SRID=8307;POINT M (12 13 14)'), 32 | (10, 'SRID=8307;POLYGON M ((0 0 0, 1 0 2, 1 1 4, 0 1 2, 0 0 0))'); 33 | 34 | /* 35 | * Test empty geometries. 36 | */ 37 | 38 | UPDATE gis SET g = 'POINT Z EMPTY' WHERE id = 1; 39 | UPDATE gis SET g = 'MULTIPOLYGON(((10 10,20 10,20 20,10 20,10 10)),EMPTY)' WHERE id = 8; 40 | 41 | /* 42 | * Test four-dimensional geometry. 43 | */ 44 | 45 | UPDATE gis SET g = 'POINT ZM (12 13 14 15)'; 46 | 47 | /* 48 | * Test SELECT and UPDATE ... RETURNING. 49 | */ 50 | 51 | -- simple SELECT 52 | SELECT id, st_srid(g), st_astext(g) FROM gis ORDER BY id; 53 | -- UPDATE with RETURNING clause 54 | WITH upd (id, srid, wkt) AS 55 | (UPDATE gis SET g=g RETURNING id, st_srid(g), st_astext(g)) 56 | SELECT * FROM upd ORDER BY id; 57 | -------------------------------------------------------------------------------- /sql/oracle_import.sql: -------------------------------------------------------------------------------- 1 | SET client_min_messages = WARNING; 2 | 3 | CREATE SCHEMA import; 4 | 5 | /* first, import only a table and a materialized view */ 6 | IMPORT FOREIGN SCHEMA "SCOTT" 7 | LIMIT TO ("typetest1", ttv, mattest2) 8 | FROM SERVER oracle 9 | INTO import 10 | OPTIONS (case 'lower', collation 'C', skip_views 'true'); 11 | 12 | SELECT t.relname, fs.srvname, ft.ftoptions 13 | FROM pg_foreign_table ft 14 | JOIN pg_class t ON ft.ftrelid = t.oid 15 | JOIN pg_foreign_server fs ON ft.ftserver = fs.oid 16 | WHERE relnamespace = 'import'::regnamespace 17 | ORDER BY t.relname; 18 | 19 | /* then import only a view */ 20 | IMPORT FOREIGN SCHEMA "SCOTT" 21 | LIMIT TO ("typetest1", ttv, mattest2) 22 | FROM SERVER oracle 23 | INTO import 24 | OPTIONS (case 'lower', skip_tables 'true', skip_matviews 'true'); 25 | 26 | SELECT t.relname, fs.srvname, ft.ftoptions 27 | FROM pg_foreign_table ft 28 | JOIN pg_class t ON ft.ftrelid = t.oid 29 | JOIN pg_foreign_server fs ON ft.ftserver = fs.oid 30 | WHERE relnamespace = 'import'::regnamespace 31 | ORDER BY t.relname; 32 | 33 | SELECT t.relname, a.attname, a.atttypid::regtype, a.attfdwoptions 34 | FROM pg_attribute AS a 35 | JOIN pg_class AS t ON t.oid = a.attrelid 36 | WHERE t.relname IN ('typetest1', 'ttv', 'mattest2') 37 | AND a.attnum > 0 38 | AND t.relnamespace = 'import'::regnamespace 39 | AND NOT a.attisdropped 40 | ORDER BY t.relname, a.attnum; 41 | -------------------------------------------------------------------------------- /sql/oracle_join.sql: -------------------------------------------------------------------------------- 1 | \pset border 1 2 | \pset linestyle ascii 3 | \set VERBOSITY terse 4 | SET client_min_messages = INFO; 5 | 6 | /* analyze table for reliable output */ 7 | ANALYZE typetest1; 8 | 9 | /* default setting sometimes leads to merge joins */ 10 | SET enable_mergejoin = off; 11 | 12 | /* 13 | * Cases that should be pushed down. 14 | */ 15 | -- inner join two tables 16 | EXPLAIN (COSTS off) 17 | SELECT t1.id, t2.id FROM typetest1 t1, typetest1 t2 WHERE t1.c = t2.c ORDER BY t1.id, t2.id; 18 | SELECT t1.id, t2.id FROM typetest1 t1, typetest1 t2 WHERE t1.c = t2.c ORDER BY t1.id, t2.id; 19 | EXPLAIN (COSTS off) 20 | SELECT length(t1.lb), length(t2.lc) FROM typetest1 t1 JOIN typetest1 t2 ON (t1.id + t2.id = 2) ORDER BY t1.id, t2.id; 21 | SELECT length(t1.lb), length(t2.lc) FROM typetest1 t1 JOIN typetest1 t2 ON (t1.id + t2.id = 2) ORDER BY t1.id, t2.id; 22 | -- inner join two tables with ORDER BY clause, but ORDER BY does not get pushed down 23 | EXPLAIN (COSTS off) 24 | SELECT t1.id, t2.id FROM typetest1 t1 JOIN typetest1 t2 USING (ts, num) ORDER BY t1.id, t2.id; 25 | SELECT t1.id, t2.id FROM typetest1 t1 JOIN typetest1 t2 USING (ts, num) ORDER BY t1.id, t2.id; 26 | -- natural join two tables 27 | EXPLAIN (COSTS off) 28 | SELECT id FROM typetest1 NATURAL JOIN shorty ORDER BY id; 29 | SELECT id FROM typetest1 NATURAL JOIN shorty ORDER BY id; 30 | -- table with column that does not exist in Oracle (should become NULL) 31 | EXPLAIN (COSTS off) 32 | SELECT t1.id, t2.x FROM typetest1 t1 JOIN longy t2 ON t1.c = t2.c ORDER BY t1.id, t2.x; 33 | SELECT t1.id, t2.x FROM typetest1 t1 JOIN longy t2 ON t1.c = t2.c ORDER BY t1.id, t2.x; 34 | -- left outer join two tables 35 | EXPLAIN (COSTS off) 36 | SELECT t1.id, t2.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d ORDER BY t1.id, t2.id; 37 | SELECT t1.id, t2.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d ORDER BY t1.id, t2.id; 38 | -- right outer join two tables 39 | EXPLAIN (COSTS off) 40 | SELECT t1.id, t2.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d ORDER BY t1.id, t2.id; 41 | SELECT t1.id, t2.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d ORDER BY t1.id, t2.id; 42 | -- full outer join two tables 43 | EXPLAIN (COSTS off) 44 | SELECT t1.id, t2.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d ORDER BY t1.id, t2.id; 45 | SELECT t1.id, t2.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d ORDER BY t1.id, t2.id; 46 | -- joins with filter conditions 47 | ---- inner join with WHERE clause 48 | EXPLAIN (COSTS off) 49 | SELECT t1.id, t2.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d WHERE t1.id > 1 ORDER BY t1.id, t2.id; 50 | SELECT t1.id, t2.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d WHERE t1.id > 1 ORDER BY t1.id, t2.id; 51 | ---- left outer join with WHERE clause 52 | EXPLAIN (COSTS off) 53 | SELECT t1.id, t2.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d WHERE t1.id > 1 ORDER BY t1.id, t2.id; 54 | SELECT t1.id, t2.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d WHERE t1.id > 1 ORDER BY t1.id, t2.id; 55 | ---- right outer join with WHERE clause 56 | EXPLAIN (COSTS off) 57 | SELECT t1.id, t2.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d WHERE t1.id > 1 ORDER BY t1.id, t2.id; 58 | SELECT t1.id, t2.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d WHERE t1.id > 1 ORDER BY t1.id, t2.id; 59 | ---- full outer join with WHERE clause 60 | EXPLAIN (COSTS off) 61 | SELECT t1.id, t2.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d WHERE t1.id > 1 ORDER BY t1.id, t2.id; 62 | SELECT t1.id, t2.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d WHERE t1.id > 1 ORDER BY t1.id, t2.id; 63 | 64 | /* 65 | * Cases that should not be pushed down. 66 | */ 67 | -- join expression cannot be pushed down 68 | EXPLAIN (COSTS off) 69 | SELECT t1.id, t2.id FROM typetest1 t1, typetest1 t2 WHERE t1.lc = t2.lc ORDER BY t1.id, t2.id; 70 | SELECT t1.id, t2.id FROM typetest1 t1, typetest1 t2 WHERE t1.lc = t2.lc ORDER BY t1.id, t2.id; 71 | -- only one join condition cannot be pushed down 72 | EXPLAIN (COSTS off) 73 | SELECT t1.id, t2.id FROM typetest1 t1 JOIN typetest1 t2 ON t1.vc = t2.vc AND t1.lb = t2.lb ORDER BY t1.id, t2.id; 74 | SELECT t1.id, t2.id FROM typetest1 t1 JOIN typetest1 t2 ON t1.vc = t2.vc AND t1.lb = t2.lb ORDER BY t1.id, t2.id; 75 | -- condition on one table needs to be evaluated locally 76 | EXPLAIN (COSTS off) 77 | SELECT max(t1.id), min(t2.id) FROM typetest1 t1 JOIN typetest1 t2 ON t1.fl = t2.fl WHERE t1.vc || 'x' = 'shortx' ORDER BY 1, 2; 78 | SELECT max(t1.id), min(t2.id) FROM typetest1 t1 JOIN typetest1 t2 ON t1.fl = t2.fl WHERE t1.vc || 'x' = 'shortx' ORDER BY 1, 2; 79 | EXPLAIN (COSTS off) 80 | SELECT t1.c, t2.nc FROM typetest1 t1 JOIN (SELECT * FROM typetest1) t2 ON (t1.id = t2.id AND t1.c >= t2.c) ORDER BY t1.id, t2.nc; 81 | SELECT t1.c, t2.nc FROM typetest1 t1 JOIN (SELECT * FROM typetest1) t2 ON (t1.id = t2.id AND t1.c >= t2.c) ORDER BY t1.id, t2.nc; 82 | EXPLAIN (COSTS off) 83 | SELECT t1.c, t2.nc FROM typetest1 t1 LEFT JOIN (SELECT * FROM typetest1) t2 ON (t1.id = t2.id AND t1.c >= t2.c) ORDER BY t1.id, t2.nc; 84 | SELECT t1.c, t2.nc FROM typetest1 t1 LEFT JOIN (SELECT * FROM typetest1) t2 ON (t1.id = t2.id AND t1.c >= t2.c) ORDER BY t1.id, t2.nc; 85 | -- subquery with where clause cannnot be pushed down in full outer join query 86 | EXPLAIN (COSTS off) 87 | SELECT t1.c, t2.nc FROM typetest1 t1 FULL JOIN (SELECT * FROM typetest1 WHERE id > 1) t2 USING (id) ORDER BY t1.id, t2.nc; 88 | SELECT t1.c, t2.nc FROM typetest1 t1 FULL JOIN (SELECT * FROM typetest1 WHERE id > 1) t2 USING (id) ORDER BY t1.id, t2.nc; 89 | -- left outer join with placeholder, not pushed down 90 | EXPLAIN (COSTS off) 91 | SELECT t1.id, sq1.x, sq1.y 92 | FROM typetest1 t1 LEFT OUTER JOIN (SELECT id AS x, 99 AS y FROM typetest1 t2 WHERE id > 1) sq1 ON t1.id = sq1.x ORDER BY t1.id, sq1.x; 93 | SELECT t1.id, sq1.x, sq1.y 94 | FROM typetest1 t1 LEFT OUTER JOIN (SELECT id AS x, 99 AS y FROM typetest1 t2 WHERE id > 1) sq1 ON t1.id = sq1.x ORDER BY t1.id, sq1.x; 95 | -- inner join with placeholder, not pushed down 96 | EXPLAIN (COSTS off) 97 | SELECT subq2.c3 98 | FROM typetest1 99 | RIGHT JOIN (SELECT c AS c1 FROM typetest1) AS subq1 ON TRUE 100 | LEFT JOIN (SELECT ref1.nc AS c2, 10 AS c3 FROM typetest1 AS ref1 101 | INNER JOIN typetest1 AS ref2 ON ref1.fl = ref2.fl) AS subq2 102 | ON subq1.c1 = subq2.c2 ORDER BY subq2.c3; 103 | SELECT subq2.c3 104 | FROM typetest1 105 | RIGHT JOIN (SELECT c AS c1 FROM typetest1) AS subq1 ON TRUE 106 | LEFT JOIN (SELECT ref1.nc AS c2, 10 AS c3 FROM typetest1 AS ref1 107 | INNER JOIN typetest1 AS ref2 ON ref1.fl = ref2.fl) AS subq2 108 | ON subq1.c1 = subq2.c2 ORDER BY subq2.c3; 109 | -- inner rel is false, not pushed down 110 | EXPLAIN (COSTS off) 111 | SELECT 1 FROM (SELECT 1 FROM typetest1 WHERE false) AS subq1 RIGHT JOIN typetest1 AS ref1 ON NULL ORDER BY ref1.id; 112 | SELECT 1 FROM (SELECT 1 FROM typetest1 WHERE false) AS subq1 RIGHT JOIN typetest1 AS ref1 ON NULL ORDER BY ref1.id; 113 | -- semi-join, not pushed down 114 | EXPLAIN (COSTS off) 115 | SELECT t1.id FROM typetest1 t1 WHERE EXISTS (SELECT 1 FROM typetest1 t2 WHERE t1.d = t2.d) ORDER BY t1.id; 116 | SELECT t1.id FROM typetest1 t1 WHERE EXISTS (SELECT 1 FROM typetest1 t2 WHERE t1.d = t2.d) ORDER BY t1.id; 117 | -- anti-join, not pushed down 118 | EXPLAIN (COSTS off) 119 | SELECT t1.id FROM typetest1 t1 WHERE NOT EXISTS (SELECT 1 FROM typetest1 t2 WHERE t1.d = t2.d) ORDER BY t1.id; 120 | SELECT t1.id FROM typetest1 t1 WHERE NOT EXISTS (SELECT 1 FROM typetest1 t2 WHERE t1.d = t2.d) ORDER BY t1.id; 121 | -- cross join, not pushed down 122 | EXPLAIN (COSTS off) 123 | SELECT t1.id, t2.id FROM typetest1 t1 CROSS JOIN typetest1 t2 ORDER BY t1.id, t2.id; 124 | SELECT t1.id, t2.id FROM typetest1 t1 CROSS JOIN typetest1 t2 ORDER BY t1.id, t2.id; 125 | EXPLAIN (COSTS off) 126 | SELECT t1.id, t2.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON true ORDER BY t1.id, t2.id; 127 | SELECT t1.id, t2.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON true ORDER BY t1.id, t2.id; 128 | EXPLAIN (COSTS off) 129 | SELECT t1.id, t2.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON true ORDER BY t1.id, t2.id; 130 | SELECT t1.id, t2.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON true ORDER BY t1.id, t2.id; 131 | EXPLAIN (COSTS off) 132 | SELECT t1.id, t2.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON true ORDER BY t1.id, t2.id; 133 | SELECT t1.id, t2.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON true ORDER BY t1.id, t2.id; 134 | EXPLAIN (COSTS off) 135 | SELECT t1.id, t2.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON true ORDER BY t1.id, t2.id; 136 | SELECT t1.id, t2.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON true ORDER BY t1.id, t2.id; 137 | EXPLAIN (COSTS off) 138 | SELECT t1.id, t2.id FROM typetest1 t1 CROSS JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ORDER BY t1.id, t2.id; 139 | SELECT t1.id, t2.id FROM typetest1 t1 CROSS JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ORDER BY t1.id, t2.id; 140 | EXPLAIN (COSTS off) 141 | SELECT t1.id, t2.id FROM typetest1 t1 INNER JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ON true ORDER BY t1.id, t2.id; 142 | SELECT t1.id, t2.id FROM typetest1 t1 INNER JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ON true ORDER BY t1.id, t2.id; 143 | EXPLAIN (COSTS off) 144 | SELECT t1.id, t2.id FROM typetest1 t1 LEFT JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ON true ORDER BY t1.id, t2.id; 145 | SELECT t1.id, t2.id FROM typetest1 t1 LEFT JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ON true ORDER BY t1.id, t2.id; 146 | EXPLAIN (COSTS off) 147 | SELECT t1.id, t2.id FROM typetest1 t1 RIGHT JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ON true ORDER BY t1.id, t2.id; 148 | SELECT t1.id, t2.id FROM typetest1 t1 RIGHT JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ON true ORDER BY t1.id, t2.id; 149 | EXPLAIN (COSTS off) 150 | SELECT t1.id, t2.id FROM typetest1 t1 FULL JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ON true ORDER BY t1.id, t2.id; 151 | SELECT t1.id, t2.id FROM typetest1 t1 FULL JOIN (SELECT * FROM typetest1 WHERE vc = 'short') t2 ON true ORDER BY t1.id, t2.id; 152 | -- update statement, not pushed down 153 | EXPLAIN (COSTS off) UPDATE typetest1 t1 SET c = NULL FROM typetest1 t2 WHERE t1.vc = t2.vc AND t2.num = 3.14159; 154 | -- join with FOR UPDATE, not pushed down 155 | EXPLAIN (COSTS off) SELECT t1.id FROM typetest1 t1, typetest1 t2 WHERE t1.id = t2.id FOR UPDATE; 156 | -- join in CTE 157 | WITH t (t1_id, t2_id) AS (SELECT t1.id, t2.id FROM typetest1 t1 JOIN typetest1 t2 ON t1.d = t2.d) SELECT t1_id, t2_id FROM t ORDER BY t1_id, t2_id; 158 | -- whole-row and system columns, not pushed down 159 | EXPLAIN (COSTS off) 160 | SELECT t1, t1.ctid FROM shorty t1 INNER JOIN longy t2 ON t1.id = t2.id ORDER BY t1.id; 161 | SELECT t1, t1.ctid FROM shorty t1 INNER JOIN longy t2 ON t1.id = t2.id ORDER BY t1.id; 162 | EXPLAIN (COSTS off) 163 | SELECT t1, t1.ctid FROM shorty t1 LEFT JOIN longy t2 ON t1.id = t2.id ORDER BY t1.id; 164 | SELECT t1, t1.ctid FROM shorty t1 LEFT JOIN longy t2 ON t1.id = t2.id ORDER BY t1.id; 165 | EXPLAIN (COSTS off) 166 | SELECT t1, t1.ctid FROM shorty t1 RIGHT JOIN longy t2 ON t1.id = t2.id ORDER BY t1.id; 167 | SELECT t1, t1.ctid FROM shorty t1 RIGHT JOIN longy t2 ON t1.id = t2.id ORDER BY t1.id; 168 | EXPLAIN (COSTS off) 169 | SELECT t1, t1.ctid FROM shorty t1 FULL JOIN longy t2 ON t1.id = t2.id ORDER BY t1.id; 170 | SELECT t1, t1.ctid FROM shorty t1 FULL JOIN longy t2 ON t1.id = t2.id ORDER BY t1.id; 171 | EXPLAIN (COSTS off) 172 | SELECT t1, t1.ctid FROM shorty t1 CROSS JOIN longy t2 ORDER BY t1.id; 173 | SELECT t1, t1.ctid FROM shorty t1 CROSS JOIN longy t2 ORDER BY t1.id; 174 | -- only part of a three-way join will be pushed down 175 | ---- inner join three tables 176 | EXPLAIN (COSTS off) 177 | SELECT t1.id, t3.id FROM typetest1 t1 JOIN typetest1 t2 USING (nvc) JOIN typetest1 t3 ON t2.db = t3.db ORDER BY t1.id, t3.id; 178 | SELECT t1.id, t3.id FROM typetest1 t1 JOIN typetest1 t2 USING (nvc) JOIN typetest1 t3 ON t2.db = t3.db ORDER BY t1.id, t3.id; 179 | EXPLAIN (COSTS off) 180 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d INNER JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 181 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d INNER JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 182 | ---- inner outer join + left outer join 183 | EXPLAIN (COSTS off) 184 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d LEFT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 185 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d LEFT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 186 | ---- inner outer join + right outer join 187 | EXPLAIN (COSTS off) 188 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d RIGHT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 189 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d RIGHT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 190 | ---- inner outer join + full outer join 191 | EXPLAIN (COSTS off) 192 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d FULL JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 193 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 INNER JOIN typetest1 t2 ON t1.d = t2.d FULL JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 194 | ---- left outer join three tables 195 | EXPLAIN (COSTS off) 196 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d LEFT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 197 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d LEFT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 198 | ---- left outer join + inner outer join 199 | EXPLAIN (COSTS off) 200 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d INNER JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 201 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d INNER JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 202 | ---- left outer join + right outer join 203 | EXPLAIN (COSTS off) 204 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d RIGHT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 205 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d RIGHT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 206 | ---- left outer join + full outer join 207 | EXPLAIN (COSTS off) 208 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d FULL JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 209 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 LEFT JOIN typetest1 t2 ON t1.d = t2.d FULL JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 210 | ---- right outer join three tables 211 | EXPLAIN (COSTS off) 212 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d RIGHT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 213 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d RIGHT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 214 | ---- right outer join + inner outer join 215 | EXPLAIN (COSTS off) 216 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d INNER JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 217 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d INNER JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 218 | ---- right outer join + left outer join 219 | EXPLAIN (COSTS off) 220 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d LEFT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 221 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d LEFT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 222 | ---- right outer join + full outer join 223 | EXPLAIN (COSTS off) 224 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d FULL JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 225 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 RIGHT JOIN typetest1 t2 ON t1.d = t2.d FULL JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 226 | ---- full outer join three tables 227 | EXPLAIN (COSTS off) 228 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d FULL JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 229 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d FULL JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 230 | ---- full outer join + inner join 231 | EXPLAIN (COSTS off) 232 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d INNER JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 233 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d INNER JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 234 | ---- full outer join + left outer join 235 | EXPLAIN (COSTS off) 236 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d LEFT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 237 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d LEFT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 238 | ---- full outer join + right outer join 239 | EXPLAIN (COSTS off) 240 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d RIGHT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 241 | SELECT t1.id, t2.id, t3.id FROM typetest1 t1 FULL JOIN typetest1 t2 ON t1.d = t2.d RIGHT JOIN typetest1 t3 ON t2.d = t3.d ORDER BY t1.id, t2.id; 242 | -- join with LATERAL reference 243 | EXPLAIN (COSTS off) 244 | SELECT t1.id, sl.c FROM typetest1 t1, LATERAL (SELECT DISTINCT s.c FROM shorty s, longy l WHERE s.id = l.id AND l.c = t1.c) sl ORDER BY t1.id, sl.c; 245 | SELECT t1.id, sl.c FROM typetest1 t1, LATERAL (SELECT DISTINCT s.c FROM shorty s, longy l WHERE s.id = l.id AND l.c = t1.c) sl ORDER BY t1.id, sl.c; 246 | -- test for bug #279 fixed with 839b125e1bdc63b71220ccd675fa852c028de9ea 247 | SELECT 1 248 | FROM typetest1 a 249 | LEFT JOIN typetest1 b ON (a.id IS NOT NULL) 250 | WHERE (a.c = a.vc) = (b.id IS NOT NULL); 251 | 252 | /* 253 | * Cost estimates. 254 | */ 255 | -- gather statistics 256 | ANALYZE typetest1; 257 | -- costs with statistics 258 | EXPLAIN SELECT t1.id, t2.id FROM typetest1 t1, typetest1 t2 WHERE t1.c = t2.c; 259 | EXPLAIN SELECT t1.id, t2.id FROM typetest1 t1, typetest1 t2 WHERE t1.c <> t2.c; 260 | --------------------------------------------------------------------------------