File: sql_migration06.md

package info (click to toggle)
orafce 4.16.3-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 2,856 kB
  • sloc: ansic: 12,914; sql: 8,984; lex: 1,054; makefile: 131; yacc: 82; python: 7; sh: 2
file content (2605 lines) | stat: -rw-r--r-- 72,816 bytes parent folder | download | duplicates (3)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
1606
1607
1608
1609
1610
1611
1612
1613
1614
1615
1616
1617
1618
1619
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
1644
1645
1646
1647
1648
1649
1650
1651
1652
1653
1654
1655
1656
1657
1658
1659
1660
1661
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
1679
1680
1681
1682
1683
1684
1685
1686
1687
1688
1689
1690
1691
1692
1693
1694
1695
1696
1697
1698
1699
1700
1701
1702
1703
1704
1705
1706
1707
1708
1709
1710
1711
1712
1713
1714
1715
1716
1717
1718
1719
1720
1721
1722
1723
1724
1725
1726
1727
1728
1729
1730
1731
1732
1733
1734
1735
1736
1737
1738
1739
1740
1741
1742
1743
1744
1745
1746
1747
1748
1749
1750
1751
1752
1753
1754
1755
1756
1757
1758
1759
1760
1761
1762
1763
1764
1765
1766
1767
1768
1769
1770
1771
1772
1773
1774
1775
1776
1777
1778
1779
1780
1781
1782
1783
1784
1785
1786
1787
1788
1789
1790
1791
1792
1793
1794
1795
1796
1797
1798
1799
1800
1801
1802
1803
1804
1805
1806
1807
1808
1809
1810
1811
1812
1813
1814
1815
1816
1817
1818
1819
1820
1821
1822
1823
1824
1825
1826
1827
1828
1829
1830
1831
1832
1833
1834
1835
1836
1837
1838
1839
1840
1841
1842
1843
1844
1845
1846
1847
1848
1849
1850
1851
1852
1853
1854
1855
1856
1857
1858
1859
1860
1861
1862
1863
1864
1865
1866
1867
1868
1869
1870
1871
1872
1873
1874
1875
1876
1877
1878
1879
1880
1881
1882
1883
1884
1885
1886
1887
1888
1889
1890
1891
1892
1893
1894
1895
1896
1897
1898
1899
1900
1901
1902
1903
1904
1905
1906
1907
1908
1909
1910
1911
1912
1913
1914
1915
1916
1917
1918
1919
1920
1921
1922
1923
1924
1925
1926
1927
1928
1929
1930
1931
1932
1933
1934
1935
1936
1937
1938
1939
1940
1941
1942
1943
1944
1945
1946
1947
1948
1949
1950
1951
1952
1953
1954
1955
1956
1957
1958
1959
1960
1961
1962
1963
1964
1965
1966
1967
1968
1969
1970
1971
1972
1973
1974
1975
1976
1977
1978
1979
1980
1981
1982
1983
1984
1985
1986
1987
1988
1989
1990
1991
1992
1993
1994
1995
1996
1997
1998
1999
2000
2001
2002
2003
2004
2005
2006
2007
2008
2009
2010
2011
2012
2013
2014
2015
2016
2017
2018
2019
2020
2021
2022
2023
2024
2025
2026
2027
2028
2029
2030
2031
2032
2033
2034
2035
2036
2037
2038
2039
2040
2041
2042
2043
2044
2045
2046
2047
2048
2049
2050
2051
2052
2053
2054
2055
2056
2057
2058
2059
2060
2061
2062
2063
2064
2065
2066
2067
2068
2069
2070
2071
2072
2073
2074
2075
2076
2077
2078
2079
2080
2081
2082
2083
2084
2085
2086
2087
2088
2089
2090
2091
2092
2093
2094
2095
2096
2097
2098
2099
2100
2101
2102
2103
2104
2105
2106
2107
2108
2109
2110
2111
2112
2113
2114
2115
2116
2117
2118
2119
2120
2121
2122
2123
2124
2125
2126
2127
2128
2129
2130
2131
2132
2133
2134
2135
2136
2137
2138
2139
2140
2141
2142
2143
2144
2145
2146
2147
2148
2149
2150
2151
2152
2153
2154
2155
2156
2157
2158
2159
2160
2161
2162
2163
2164
2165
2166
2167
2168
2169
2170
2171
2172
2173
2174
2175
2176
2177
2178
2179
2180
2181
2182
2183
2184
2185
2186
2187
2188
2189
2190
2191
2192
2193
2194
2195
2196
2197
2198
2199
2200
2201
2202
2203
2204
2205
2206
2207
2208
2209
2210
2211
2212
2213
2214
2215
2216
2217
2218
2219
2220
2221
2222
2223
2224
2225
2226
2227
2228
2229
2230
2231
2232
2233
2234
2235
2236
2237
2238
2239
2240
2241
2242
2243
2244
2245
2246
2247
2248
2249
2250
2251
2252
2253
2254
2255
2256
2257
2258
2259
2260
2261
2262
2263
2264
2265
2266
2267
2268
2269
2270
2271
2272
2273
2274
2275
2276
2277
2278
2279
2280
2281
2282
2283
2284
2285
2286
2287
2288
2289
2290
2291
2292
2293
2294
2295
2296
2297
2298
2299
2300
2301
2302
2303
2304
2305
2306
2307
2308
2309
2310
2311
2312
2313
2314
2315
2316
2317
2318
2319
2320
2321
2322
2323
2324
2325
2326
2327
2328
2329
2330
2331
2332
2333
2334
2335
2336
2337
2338
2339
2340
2341
2342
2343
2344
2345
2346
2347
2348
2349
2350
2351
2352
2353
2354
2355
2356
2357
2358
2359
2360
2361
2362
2363
2364
2365
2366
2367
2368
2369
2370
2371
2372
2373
2374
2375
2376
2377
2378
2379
2380
2381
2382
2383
2384
2385
2386
2387
2388
2389
2390
2391
2392
2393
2394
2395
2396
2397
2398
2399
2400
2401
2402
2403
2404
2405
2406
2407
2408
2409
2410
2411
2412
2413
2414
2415
2416
2417
2418
2419
2420
2421
2422
2423
2424
2425
2426
2427
2428
2429
2430
2431
2432
2433
2434
2435
2436
2437
2438
2439
2440
2441
2442
2443
2444
2445
2446
2447
2448
2449
2450
2451
2452
2453
2454
2455
2456
2457
2458
2459
2460
2461
2462
2463
2464
2465
2466
2467
2468
2469
2470
2471
2472
2473
2474
2475
2476
2477
2478
2479
2480
2481
2482
2483
2484
2485
2486
2487
2488
2489
2490
2491
2492
2493
2494
2495
2496
2497
2498
2499
2500
2501
2502
2503
2504
2505
2506
2507
2508
2509
2510
2511
2512
2513
2514
2515
2516
2517
2518
2519
2520
2521
2522
2523
2524
2525
2526
2527
2528
2529
2530
2531
2532
2533
2534
2535
2536
2537
2538
2539
2540
2541
2542
2543
2544
2545
2546
2547
2548
2549
2550
2551
2552
2553
2554
2555
2556
2557
2558
2559
2560
2561
2562
2563
2564
2565
2566
2567
2568
2569
2570
2571
2572
2573
2574
2575
2576
2577
2578
2579
2580
2581
2582
2583
2584
2585
2586
2587
2588
2589
2590
2591
2592
2593
2594
2595
2596
2597
2598
2599
2600
2601
2602
2603
2604
2605
Chapter 6 Notes on Using orafce
---

This chapter provides notes on using Oracle database compatibility features added by orafce.

### 6.1 Data Types
This section explains how to migrate data types added by orafce.

#### 6.1.1 Notes on VARCHAR2
This section provides notes on VARCHAR2.

##### 6.1.1.1 Specifying the Maximum Number of Bytes and Maximum Number of Characters

**Functional differences**

 - **Oracle database**
     - Specifying the keyword BYTE or CHAR after a size enables the size to be indicated in terms of the maximum number of bytes or the maximum number of characters.
 - **PostgreSQL**
     - The keyword BYTE or CHAR cannot be set after the size.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword VARCHAR2 and check if the keyword BYTE or CHAR is specified after the size.
 2. If the BYTE keyword is specified, delete it.
 3. If the CHAR keyword is specified, delete it and convert the data type to VARCHAR.

**Migration example**

The example below shows migration when the maximum number of bytes or the maximum number of characters for the VARCHAR2 type is specified.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code>CREATE TABLE t1( 
  col1 VARCHAR2<b>(5 BYTE)</b>, 
  col2 <b>VARCHAR2(5 CHAR)</b> 
 );</code></pre>
</td>

<td align="left">
<pre><code>CREATE TABLE t1( 
  col1 VARCHAR2<b>(5)</b>, 
  col2 <b>VARCHAR(5)</b> 
 );</code></pre>
</td>
</tr>
</tbody>
</table>


**Note**

----

The VARCHAR2 type does not support collating sequences. Therefore, the following error occurs when a collating sequence like that of an ORDER BY clause is required. At this time, the following HINT will prompt to use a COLLATE clause, however, because collating sequences are not supported, it is not possible to use this clause.

~~~
ERROR:  could not determine which collation to use for string comparison
HINT:  Use the COLLATE clause to set the collation explicitly.

~~~

If the error shown above is displayed, explicitly cast the column to VARCHAR or TEXT type.

----

### 6.2 Functions
This section explains how to migrate functions added by orafce.

#### 6.2.1 INSTRB
**Description**

INSTRB searches for a substring in a string and returns the start position (in bytes) of the first occurrence of the substring.
##### 6.2.1.1 Obtaining the Start Position of a Substring (in Bytes)
**Functional differences**

 - **Oracle database**
     - INSTRB searches for a substring in a string and returns the start position (in bytes) of the substring.
 - **PostgreSQL**
     - There is no INSTRB function. Use STRPOSB instead. STRPOSB is unique to orafce.

**Migration procedure**

Use the following procedure to migrate to STRPOSB:

 1. Search for the keyword INSTRB and identify where it is used.
 2. Confirm that arguments up to the second argument are specified.
 3. Change INSTRB to STRPOSB.

**Migration example**

The example below shows migration when searching for a particular substring in a string, and returning the start position of the substring in bytes.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code>SELECT c_code, <b>INSTRB</b>( c_address, ',' ) 
  FROM company_table;</code></pre>
</td>

<td align="left">
<pre><code>SELECT c_code, <b>STRPOSB</b>( c_address, ',' ) 
  FROM company_table;</code></pre>
</td>
</tr>
</tbody>
</table>


**Note**

----

If the third argument is specified in INSTRB, refer to the conversion example shown below. If the fourth argument is specified, migration is not possible.

----

**Information**

----

The general rules for STRPOSB are as follows:

----

**Description**

INSTRB returns the start position (in bytes) of a substring within a string.

**Specification format**

![STRPOSB](gif/STRPOSB.gif)

**General rules**

 - STRPOSB searches for string *str2* in *str1* and returns the start position it finds in bytes.
 - If *str2* is not found, 0 is returned.
 - The data type of the return value is INTEGER.

##### 6.2.1.2 Obtaining the Start Position of a Substring from a Specified Search Start Position (in Bytes)

**Functional differences**

 - **Oracle database**
     - The search start position is specified in the third argument of INSTRB.
 - **PostgreSQL**
     - A search start position cannot be specified with STRPOSB.

**Migration procedure**

A search start position cannot be specified, so truncate the search target string to the start position so that the same result is returned. Use the following procedure to perform migration:

 1. Search for the keyword INSTRB and identify where it is used.
 2. Confirm that arguments up to the third argument are specified and that a positive number is specified.
 3. Enclose the string specified in the first argument with SUBSTRB, and specify the value specified in the third argument of INSTRB as the second argument of SUBSTRB.
 4. Change INSTRB to STRPOSB and delete the value specified in the third argument.
 5. Enclose the function in a simple CASE expression to evaluate the result of the function changed in step 4. <br> Define the selector so that 0 is returned when the result is 0. <br> If the result is not 0, specify the same function as in step 4, and add the value obtained by subtracting 1 from the value specified in the second argument of SUBSTRB.

**Migration example**

The example below shows migration when a search start position is specified and then the start position of a string is found in bytes.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code>SELECT c_code, <b>INSTRB( c_address, '-', 10 )</b> 
 FROM company_table; 
<br>
<br>
<br>
<br>
 </code></pre>
</td>

<td align="left">
<pre><code>SELECT c_code, 
 <b>CASE STRPOSB( SUBSTRB( c_address, 10 ),'-') 
 WHEN 0 THEN 0 
 ELSE STRPOSB( SUBSTRB( c_address, 10 ), '-' ) + 9 
 END</b> 
 FROM company_table;</code></pre>
</td>
</tr>
</tbody>
</table>



#### 6.2.2 INSTRC, INSTR2, and INSTR4

**Description**

INSTRC, INSTR2, and INSTR4 return the start position of a substring in a string using the relevant encoding.

**Functional differences**

 - **Oracle database**
     - INSTRC, INSTR2, and INSTR4 use the relevant encoding to search for a substring in a string from a specified position and then return the start position of the substring.
 - **PostgreSQL**
     - There are no INSTRC, INSTR2, and INSTR4 functions. Only Unicode encoding is used in PostgreSQL.

**Migration procedure**

Use the following procedure to migrate to INSTR:

 1. Search for the keywords INSTRC, INSTR2, and INSTR4, and identify where they are used.
 2. Change those keywords to INSTR.

**Migration example**

The example below shows migration from INSTRC, INSTR2, and INSTR4.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT c_name, <b>INSTRC</b>( c_name, 'Corp', 2, 1 ) 
  FROM company_table; 
<br>
 SELECT c_name, <b>INSTR2</b>( c_name, 'Corp', 2, 1 ) 
  FROM company_table; 
<br>
 SELECT c_name, <b>INSTR4</b>( c_name, 'Corp', 2, 1 ) 
  FROM company_table;</code></pre>
</td>

<td align="left">
<pre><code>SELECT c_name, <b>INSTR</b>( c_name, 'Corp', 2, 1 ) 
  FROM company_table; 
<br>
<br>
<br>
<br>
<br>
<br>
 </code></pre>
</td>
</tr>
</tbody>
</table>


#### 6.2.3 LENGTHC, LENGTH2, and LENGTH4

**Description**

LENGTHC, LENGTH2, and LENGTH4 use the relevant encoding to return the length of the specified string.

**Functional differences**

 - **Oracle database**
     - LENGTHC, LENGTH2, and LENGTH4 use the relevant encoding to return the length of the specified string.
 - **PostgreSQL**
     - There are no LENGTHC, LENGTH2, and LENGTH4 functions. Only Unicode encoding is used in PostgreSQL.

**Migration procedure**

Use the following procedure to migrate to LENGTH:

 1. Search for the keywords LENGTHC, LENGTH2, and LENGTH4, and identify where they are used.
 2. Change those keywords to LENGTH.

**Migration example**

The example below shows migration from LENGTHC, LENGTH2, and LENGTH4.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT name, <b>LENGTHC</b>( name ) 
  FROM staff_table 
  WHERE job = 'sales member'; 
<br>
 SELECT name, <b>LENGTH2</b>( name ) 
  FROM staff_table 
  WHERE job = 'sales member'; 
<br>
 SELECT name, <b>LENGTH4</b>( name ) 
  FROM staff_table 
  WHERE job = 'sales member';</code></pre>
</td>

<td align="left">
<pre><code> SELECT name, <b>LENGTH</b>( name ) 
  FROM staff_table 
  WHERE job = 'sales member'; 
<br>
<br>
<br>
<br>
<br>
<br>
<br>
<br>
 </code></pre>
</td>
</tr>
</tbody>
</table>



#### 6.2.4 LISTAGG

**Description**

LISTAGG returns a concatenated, delimited list of string values.

##### 6.2.4.1 Specifying the Join Sequence for a List

**Functional differences**

 - **Oracle database**
     - The join sequence for a list is specified using WITHIN GROUP(ORDER BY).
 - **PostgreSQL**
     - WITHIN GROUP(ORDER BY) cannot be used. Instead, a join sequence can be specified using ORDER BY immediately after the value.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword LISTAGG and confirm where it is used.
 2. Move the ORDER BY clause of WITHIN GROUP(ORDER BY) immediately after the value of LISTAGG and then delete WITHIN GROUP().

**Migration example**

The example below shows migration of the join sequence of specified values.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT manager_id, 
        LISTAGG( name, ', ' ) 
         <b>WITHIN GROUP( ORDER BY staff_id )</b> 
  FROM staff_table 
  GROUP BY manager_id;</code></pre>
</td>

<td align="left">
<pre><code> SELECT manager_id, 
        LISTAGG( name, ', ' <b>ORDER BY staff_id</b> ) 
<br>
  FROM staff_table 
  GROUP BY manager_id;</code></pre>
</td>
</tr>
</tbody>
</table>


##### 6.2.4.2 Specifying the Join Sequence for a List per Group (Window Functions)

**Functional differences**

 - **Oracle database**
     - The join sequence for a list per group is specified using WITHIN GROUP(ORDER BY) OVER(PARTITION BY).
 - **PostgreSQL**
     - The join sequence for a list per group cannot be specified.

**Migration procedure**

The join sequence for a list per group cannot be specified, so sort the data into the sequence in which it is to be joined and then join it. Use the following procedure to perform migration:
 
 1. Search for the keywords LISTAGG and OVER, and identify where the OVER clause of LISTAGG is used.
 2. Convert the table in the FROM clause to a subquery, and move the ORDER BY clause of WITHIN GROUP(ORDER BY) to the subquery.
 3. Delete WITHIN GROUP(ORDER BY).

**Migration example**

The example below shows migration when a join sequence for a list per group is specified.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT name, 
        manager_id, 
        LISTAGG( name, ', ' ) 
         <b>WITHIN GROUP( ORDER BY staff_id )</b> 
         OVER( PARTITION BY manager_id )  
  FROM <b>staff_table;</b> 
<br>
 </code></pre>
</td>

<td align="left">
<pre><code> SELECT name, 
        manager_id, 
        LISTAGG( name, ', ' ) 
<br>
         OVER( PARTITION BY manager_id ) 
  FROM <b>( SELECT * FROM staff_table 
          ORDER BY staff_id ) st_tbl;</b> 
 </code></pre>
</td>
</tr>
</tbody>
</table>


#### 6.2.5 NLSSORT
**Description**

NLSSORT returns a binary value that denotes the lexical order of the locale (COLLATE).

##### 6.2.5.1 Sorting by the Specified Locale

**Functional differences**

 - **Oracle database**
     - The locale is specified by NLS_SORT=locale.<br> The specifiable locales are provided by the Oracle database.
 - **PostgreSQL**
     - The locale is specified by locale. <br> The specifiable locales depend on the operating system.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword NLSSORT and identify where it is used.
 2. Delete NLS_SORT= and change the locale to the locale used by the operating system corresponding to the specified collating sequence.

**Migration example**

The example below shows migration when the specified locale is used for sorting. Note that the example locale in PostgreSQL would be the value specified for Linux.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, 
                    <b>'NLS_SORT = xDanish'</b> ); 
<br>
 SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, 
                    <b>'NLS_SORT = JAPANESE_M'</b> );</code></pre>
</td>

<td align="left">
<pre><code> SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, <b>'danish'</b> ); 
<br>
<br>
 SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( c_name, <b>'ja_JP.UTF8'</b> ); 
 </code></pre>
</td>
</tr>
</tbody>
</table>



##### 6.2.5.2 Sorting by Character Set

**Functional differences**

 - **Oracle database**
     - NLS_SORT=BINARY is specified in the locale specification for sorting by character set.
 - **PostgreSQL**
     - C is specified in the locale specification for sorting by character set.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword NLSSORT and identify where it is used.
 2. If NLS_SORT=BINARY is specified for the locale, change it to C.

**Migration example**

The example below shows migration when the character set is used for sorting.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT c_code, c_name 
  FROM company_table 
  ORDER BY <b>NLSSORT( c_name, 'NLS_SORT = BINARY' );</b></code></pre>
</td>

<td align="left">
<pre><code> SELECT c_code, c_name 
  FROM company_table 
  ORDER BY <b>NLSSORT( c_name, 'C' );</b></code></pre>
</td>
</tr>
</tbody>
</table>



##### 6.2.5.3 Case-Insensitive Sorting

**Functional differences**

 - **Oracle database**
     - Specifying _CI at the end of the locale sets case-insensitive sorting.
 - **PostgreSQL**
     - _CI cannot be specified at the end of the locale.

**Migration procedure**

There are no features that perform case-insensitive sorting, so make all characters either uppercase or lowercase before starting sorting so that the same result is returned. Use the following procedure to perform migration:

 1. Search for the keyword NLSSORT and identify where it is used.
 2. If _CI is specified at the end of the specified locale, put the sort column inside the parentheses of LOWER (or UPPER).

**Migration example**

The example below shows migration when case-insensitive sorting is used.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT c_code, c_name 
  FROM company_table 
 ORDER BY NLSSORT( c_name, 
                   <b>'NLS_SORT = JAPANESE_M_CI'</b> );</code></pre>
</td>

<td align="left">
<pre><code> SELECT c_code, c_name 
  FROM company_table 
  ORDER BY NLSSORT( <b>LOWER</b>( c_name ), 
                    <b>'ja_JP.UTF8'</b> ); 
 </code></pre>
</td>
</tr>
</tbody>
</table>

#### 6.2.6 SUBSTRC, SUBSTR2, and SUBSTR4

**Description**

SUBSTRC, SUBSTR2, and SUBSTR4 extract part of a string in the character unit of the relevant encoding.

**Functional differences**

 - **Oracle database**
     - SUBSTRC, SUBSTR2, and SUBSTR4 extract part of a string in the character unit of the relevant encoding.
 - **PostgreSQL**
     - There are no SUBSTRC, SUBSTR2, and SUBSTR4 functions. Only Unicode encoding is used in PostgreSQL.

**Migration procedure**

Use the following procedure to migrate to SUBSTR:

 1. Search for the keywords SUBSTRC, SUBSTR2, and SUBSTR4, and identify where they are used.
 2. Change those keywords to SUBSTR.

**Migration example**

The example below shows migration when part of a string is extracted in the character unit of the relevant encoding.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT <b>SUBSTRC</b>( c_telephone, 5, 8 ) 
  FROM company_table; 
<br>
 SELECT <b>SUBSTR2</b>( c_telephone, 5, 8 ) 
 FROM company_table; 
<br>
 SELECT <b>SUBSTR4</b>( c_telephone, 5, 8 ) 
  FROM company_table;</code></pre>
</td>

<td align="left">
<pre><code> SELECT <b>SUBSTR</b>( c_telephone, 5, 8 ) 
  FROM company_table; 
<br>
<br>
<br>
<br>
<br>
<br>
 </code></pre>
</td>
</tr>
</tbody>
</table>



#### 6.2.7 SUBSTRB
**Description**

SUBSTRB extracts part of a string in bytes.

##### 6.2.7.1 Specifying Zero as the Start Position
**Functional differences**

 - **Oracle database**
     - If 0 is specified as the start position, the part of the string is extracted from the first byte.
 - **PostgreSQL**
     - If 0 is specified as the start position, extraction starts at the position found by subtracting 1 from the start position and shifting by that number of positions to the left.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword SUBSTRB and identify where it is used.
 2. If 0 is specified as the start position, change it to 1.

**Migration example**

The example below shows migration when 0 is specified as the start position for SUBSTRB.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT SUBSTRB( c_telephone, <b>0</b>, 7 ) &#124;&#124; '-xxxx' 
  FROM company_table;</code></pre>
</td>

<td align="left">
<pre><code> SELECT SUBSTRB( c_telephone, <b>1</b>, 7 ) &#124;&#124; '-xxxx' 
  FROM company_table;</code></pre>
</td>
</tr>
</tbody>
</table>


##### 6.2.7.2 Specifying a Negative Value as the Start Position
**Functional differences**

 - **Oracle database**
     - If a negative value is specified as the start position, extraction starts at the position found by counting by that number of bytes after the end of the string.
 - **PostgreSQL**
     - If a negative value is specified as the start position, extraction starts at the position found by subtracting 1 from the start position and shifting by that number of positions to the left.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword SUBSTRB and identify where it is used.
 2. If a negative value is specified as the start position, add (OCTET_LENGTH(firstArgumentOfSubstrb)+1) before the negative value of the start position parameter.

**Migration example**

The example below shows migration when a negative value is specified as the start position for SUBSTRB.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT 'xxx-' &#124;&#124; 
        SUBSTRB( c_telephone, <b>-8</b>, 3 ) &#124;&#124; 
        '-xxxx' 
 FROM company_table; 
<br>
<br>
<br>
 </code></pre>
</td>

<td align="left">
<pre><code>SELECT 'xxx-' &#124;&#124; 
        SUBSTRB( c_telephone, 
                 ( <b>OCTET_LENGTH( c_telephone )  
                    +1 ) -8</b>, 
                   3 ) &#124;&#124; 
        '-xxxx' 
  FROM company_table;</code></pre>
</td>
</tr>
</tbody>
</table>

##### 6.2.7.3 Specifying a Value Less Than One as the String Length
**Functional differences**

 - **Oracle database**
     - If a value less than 1 is specified as the string length, NULL is returned.
 - **PostgreSQL**
     - If the string length is 0, a null character is returned. A negative value cannot be specified as a string length.

**Migration procedure**

Use the following procedure to perform migration. Note that the final step depends on whether NULL or a null character is expected as the return value.

 - When expecting NULL as the return value
     1. Search for the keyword SUBSTRB and identify where it is used.
     2. Confirm that a value less than 1 is specified in the string length parameter.
     3. Change the string length to NULL.
 - When expecting a null character as the return value
     1. Search for the keyword SUBSTRB and identify where it is used.
     2. Confirm that a value less than 1 is specified in the string length parameter.
     3. If a value less than 0 is specified as the string length, change it to 0.

**Migration example**

The example below shows migration when a value less than 1 is specified as the string length in SUBSTRB. In this example, NULL is expected as the return value.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT SUBSTRB( c_telephone, 1, <b>-1</b> ) 
  FROM company_table;</code></pre>
</td>

<td align="left">
<pre><code> SELECT SUBSTRB( c_telephone, 1, <b>NULL</b> ) 
  FROM company_table;</code></pre>
</td>
</tr>
</tbody>
</table>

#### 6.2.8 TO_CHAR and TO_DATE

**Description**

TO_CHAR and TO_DATE convert the specified value in accordance with the format.

##### 6.2.8.1 When Only Part of the TO_DATE Datetime Format is Specified

**Functional differences**

 - **Oracle database**
     - If only part of the TO_DATE datetime format is specified, the omitted portion is set automatically, with the year set to the current year, the month set to the current month, the day set to 1, and the hour, minute, and second set to 0.
 - **PostgreSQL**
     - If only part of the TO_DATE datetime format is specified, the omitted portion is set automatically, with the year, month, and day set to 1, and the hour, minute, and second set to 0.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword TO_DATE and confirm that the year or month is not specified in the datetime format.
 2. Use DATE_TRANC to find the year. If the year is omitted, specify SYSDATE to obtain the current year.
 3. Multiply the result of DATE_PART by one month indicated in the INTERVAL type to find the month. If the month is omitted, specify SYSDATE to obtain the current month.
 4. Add the results found in steps 2 and 3.

**Migration example**

The example below shows migration when only part of the TO_DATE datetime format is specified.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT <b>TO_DATE( '04', 'MM' )</b> 
  FROM DUAL;
<br>
<br>
<br>
 SELECT <b>TO_DATE( '2000', 'YYYY' )</b>  
  FROM DUAL; 
<br>
<br>
  </code></pre>
</td>

<td align="left">
<pre><code> SELECT <b>DATE_TRUNC( 'YEAR', SYSDATE() ) 
 + ( DATE_PART( 'MONTH', TO_DATE( '04', 'MM' ) ) - 1 ) 
 * INTERVAL '1 MONTH'</b> 
 FROM DUAL; 
<br>
 SELECT <b>DATE_TRUNC( 'YEAR', TO_DATE( '2000', 'YYYY' ) ) 
 + ( DATE_PART( 'MONTH', SYSDATE() ) - 1 ) 
 * INTERVAL '1 MONTH'</b> 
 FROM DUAL;</code></pre>
</td>
</tr>
</tbody>
</table>



##### 6.2.8.2 Omitting the Data Type Format

**Functional differences**

 - **Oracle database**
     - If the data type format (datetime format) is omitted from TO_DATE or TO_CHAR, the values are converted in accordance with NLS_DATE_FORMAT. <br> Statements such as ALTER SESSION can be used to change NLS_DATE_FORMAT.
 - **PostgreSQL**
     - If the data type format (datetime format) is omitted from TO_DATE or TO_CHAR, the values are converted in accordance with oracle.nls_date_format. <br> Statements such as SET can be used to change oracle.nls_date_format.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keywords TO_DATE and TO_CHAR, and check where the data type format (datetime format) is omitted.
 2. Check the settings of the NLS_DATE_FORMAT parameter.
 3. In oracle.nls_date_format, specify the datetime format specified in the NLS_DATE_FORMAT parameter.

**Migration example**

The example below shows migration when the date format is specified in the ALTER SESSION statement.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> <b>ALTER SESSION 
  SET NLS_DATE_FORMAT = "yyyy/mm/dd hh24:mi:ss";</b> 
 SELECT o_code, TO_CHAR( SYSDATE ) 
  FROM ordering_table; 
  </code></pre>
</td>

<td align="left">
<pre><code> <b>SET orafce.nls_date_format =  
     'yyyy/mm/dd hh24:mi:ss';</b> 
 SELECT o_code, 
        TO_CHAR( SYSDATE() ) 
  FROM ordering_table; 
 </code></pre>
</td>
</tr>
</tbody>
</table>

**See**

----

The scope of supported datetime formats differs between Oracle databases and PostgreSQL. Refer to "Formats" for information on the differences in the supported datetime formats.

----

##### 6.2.8.3 Setting a Data Type Format Locale (Setting the Third Argument)

**Functional differences**

 - **Oracle database**
     - The third argument (data type format locale setting) can be specified.
 - **PostgreSQL**
     - The third argument (data type format locale setting) cannot be specified.

**Migration procedure**

The locale cannot be specified in the data type format, so change the server parameters so that the same result is returned. Use the following procedure to perform migration:

 1. Search for the keywords TO_CHAR and TO_DATE, and identify where they are used.
 2. If the third argument is specified, use a SET statement to specify the corresponding server parameter to match the string format locale to be converted. The table below shows the correspondence between the parameters for setting a data type format locale and the server parameters.
 3. Delete the third argument specified in TO_CHAR and TO_DATE.

**Correspondence between the parameters for setting a data type format locale and the server parameters**

|Data type format|Parameter for setting data type format locale<br>(Oracle database)|Server parameter<br>(PostgreSQL)|
|:---|:---|:---|
|Number format|NLS_NUMERIC_CHARACTERS|LC_NUMERIC (\*1)|
|Number format|NLS_CURRENCY|LC_MONETARY (\*1)|
|Number format|NLS_ISO_CURRENCY|- (Cannot be migrated because there is no corresponding parameter)|
|Datetime format|NLS_DATE_LANGUAGE|LC_TIME (\*2)(\*3)(\*4)|

\*1:	In Oracle databases, the corresponding string is specified directly, but in PostgreSQL, the locale is specified. The string that is set is the value predetermined for each locale.

\*2:	When a string that is dependent on the specified locale is to be found, the prefix TM must be added at the beginning of the date format. If the TM prefix is not specified, an English-language string will be returned.

\*3:	When a string that is dependent on a Japanese-language or other character set is to be found, the string including the encoding must be specified. (Example: SET LC_TIME='ja_JP.UTF-8')

\*4:	Migration is possible only if TO_CHAR is used to find a string from a date. If TO_DATE is used, a locale-dependent string cannot be used as input.

**Migration example**

The example below shows migration when the data type format locale is set (in the third argument).

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT o_code, 
        TO_CHAR( o_price * o_quantity / 1.2, 
                 'l999g999g999d00', 
                 <b>'NLS_NUMERIC_CHARACTERS = '',.'' 
                 NLS_CURRENCY = ''EUR'' '</b> ) "MONEY" 
   FROM ordering_table;</code></pre>
</td>

<td align="left">
<pre><code> <b>SET LC_MONETARY='de_DE'; 
 SET LC_NUMERIC='de_DE';</b> 
 SELECT o_code, 
        TO_CHAR( o_price * o_quantity / 1.2, 
                 'l999g999g999d00' ) "MONEY" 
  FROM ordering_table;</code></pre>
</td>
</tr>
</tbody>
</table>



**Information**

----

If the data type format matches the client locale, simply delete the third argument of TO_CHAR.

----

**See**

----

The values that can be specified in the server parameters depend on the locale of the operating system on the client. Refer to the PostgreSQL Documentation for details.

----

#### 6.2.9 Functions Requiring Parentheses

Some functions added by orafce do not have arguments. Parentheses must be added to these functions when they are called. The functions to which parentheses must be added are listed below.
Functions requiring parentheses:

 - SYSDATE
 - SESSIONTIMEZONE
 - DBTIMEZONE

**Migration example**

The example below shows migration when a function that has no arguments is called.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT <b>SYSDATE</b> FROM DUAL;</code></pre>
</td>

<td align="left">
<pre><code> SELECT <b>SYSDATE()</b> FROM DUAL;</code></pre>
</td>
</tr>
</tbody>
</table>

### 6.3 Standard Packages

This section explains how to migrate the standard packages added by orafce.

#### 6.3.1 DBMS_ALERT

**Description**

The DBMS_ALERT package sends alerts from a PL/pgSQL execution session to multiple other PL/pgSQL execution sessions.

##### 6.3.1.1 Set Value of DBMS_ALERT.REGISTER

**Functional differences**

 - **Oracle database**
     - The second argument of DBMS_ALERT.REGISTER can be specified. The second argument specifies whether to perform a cleanup of the pipe to be used. <br> The default is TRUE, which causes a cleanup to be performed.
 - **PostgreSQL**
     - The second argument cannot be specified.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword DBMS_ALERT.REGISTER and identify where it is used.
 2. If the second argument is specified, delete it.

**Migration example**

The example below shows migration when the second argument is specified in DBMS_ALERT.REGISTER.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> DBMS_ALERT.REGISTER( 'SAMPLEALERT', <b>TRUE</b> );</code></pre>
</td>

<td align="left">
<pre><code> PERFORM DBMS_ALERT.REGISTER( 'SAMPLEALERT' );</code></pre>
</td>
</tr>
</tbody>
</table>

##### 6.3.1.2 Case Sensitivity of Alert Names

**Functional differences**

 - **Oracle database**
     - Alert names are case-insensitive.
 - **PostgreSQL**
     - Alert names are case-sensitive.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keywords DBMS_ALERT.REGISTER, DBMS_ALERT.SIGNAL, DBMS_ALERT.WAITONE, and DBMS_ALERT.REMOVE, and identify where they are used.
 2. If there are alert names in different cases (uppercase and lowercase characters), change them to the same case.

**Migration example**

The example below shows migration when there is an alert name in uppercase characters and an alert name in lowercase characters. In this example, the alert names are aligned in uppercase.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> DBMS_ALERT.REGISTER( 'SAMPLEALERT', <b>TRUE</b> ); 
 ~ 
 DBMS_ALERT.SIGNAL( <b>'samplealert'</b>, 
                    'TEST MESSAGE 1' );</code></pre>
</td>

<td align="left">
<pre><code> PERFORM DBMS_ALERT.REGISTER( 'SAMPLEALERT' ); 
 ~ 
 PERFORM DBMS_ALERT.SIGNAL( <b>'SAMPLEALERT'</b>, 
                            'TEST MESSAGE 1' );</code></pre>
</td>
</tr>
</tbody>
</table>

##### 6.3.1.3 Other Notes on Using DBMS_ALERT

This section explains the functional differences to be noted when DBMS_ALERT is used. Note that PL/pgSQL features cannot migrate these functional differences. Consider, for example, changing the application logic.

###### 6.3.1.3.1 Executing DBMS_ALERT.SIGNAL from Multiple PL/pgSQL Sessions

**Functional differences**

 - **Oracle database**
     - DBMS_ALERT.SIGNAL is serialized according to the execution sequence. <br> Therefore, when DBMS_ALERT.SIGNAL is sent from multiple PL/SQL execution sessions to the same alert, <br> each DBMS_ALERT.SIGNAL remains in wait state until the preceding DBMS_ALERT.SIGNAL is committed.
 - **PostgreSQL**
     - DBMS_ALERT.SIGNAL is not serialized according to the execution sequence. <br> Therefore, even if the preceding DBMS_ALERT.SIGNAL is not yet committed, <br> the following DBMS_ALERT.SIGNAL does not enter wait state and the alert that is committed first is reported.

###### 6.3.1.3.2 Message Received when Alert is Reported Multiple Times

**Functional differences**

 - **Oracle database**
     - If multiple DBMS_ALERT.SIGNAL procedures are executed between the time that DBMS_ALERT.REGISTER is executed and DBMS_ALERT.WAITANY/WAITONE is executed, the message from the DBMS_ALERT.SIGNAL executed last is received. All earlier alert messages are discarded.
 - **PostgreSQL**
     - If multiple DBMS_ALERT.SIGNAL procedures are executed between the time that DBMS_ALERT.REGISTER is executed and DBMS_ALERT.WAITANY/WAITONE is executed, the message from the DBMS_ALERT.SIGNAL executed first is received. Subsequent alert messages are not discarded but retained.

**Note**

----

If alerts with the same name are used in multiple sessions, ensure that all alert messages are received or delete alerts from the PL/pgSQL sessions by using DBMS_ALERT.REMOVE/REMOVEALL at the point where alerts no longer need to be received. If alerts remain when the session is closed, other sessions may no longer be able to receive alerts properly.

----

##### 6.3.1.4 Example of Migrating DBMS_ALERT

The example below shows migration to PL/pgSQL when DBMS_ALERT is used.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code>(Receiving side) 
 BEGIN 
  <b>DBMS_ALERT.REGISTER( 'SAMPLEALERT', TRUE );</b> 
 END; 
 / 
<br>
<br>
 ------------------------------------------------- 
 (Sending side) 
<br>
 BEGIN 
   DBMS_ALERT.SIGNAL( <b>'samplealert'</b>, 
                      'TEST MESSAGE 1' ); 
   COMMIT; 
   DBMS_ALERT.SIGNAL( <b>'samplealert'</b>, 
                      'TEST MESSAGE 2' ); 
   COMMIT; 
 END; 
 / 
 ------------------------------------------------- 
 (Receiving side) 
 SET SERVEROUTPUT ON 
 DECLARE 
  alname VARCHAR2(100) := 'SAMPLEALERT'; 
  almess VARCHAR2(1000); 
  alst   NUMBER; 
 BEGIN 
  DBMS_ALERT.WAITONE( alname, almess, alst, 60 ); 
  DBMS_OUTPUT.PUT_LINE( alname ); 
  DBMS_OUTPUT.PUT_LINE( almess ); 
  DBMS_OUTPUT.PUT_LINE( 'alst =' &#124;&#124; alst ); 
  DBMS_ALERT.REMOVE( alname ); 
 END; 
 / 
<br>
<br>
  </code></pre>
</td>

<td align="left">
<pre><code> (Receiving side) 
 DO $$ 
 BEGIN 
  <b>PERFORM DBMS_ALERT.REGISTER( 'SAMPLEALERT' );</b> 
 END; 
 $$ 
 ; 
 ------------------------------------------------- 
 (Sending side) 
 DO $$ 
 BEGIN 
  PERFORM DBMS_ALERT.SIGNAL( <b>'SAMPLEALERT'</b>, 
                             'TEST MESSAGE 1' ); 
  PERFORM DBMS_ALERT.SIGNAL( <b>'SAMPLEALERT'</b>, 
                             'TEST MESSAGE 2' ); 
 END; 
 $$ 
 ; 
<br>
 ------------------------------------------------- 
 (Receiving side) 
 DO $$ 
 DECLARE 
  alname VARCHAR2(100) := 'SAMPLEALERT'; 
  almess VARCHAR2(1000); 
  alst   int; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
  SELECT message, status INTO almess, alst 
   FROM DBMS_ALERT.WAITONE( alname, 60 ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( alname ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( almess ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( 'alst =' &#124;&#124; alst ); 
  PERFORM DBMS_ALERT.REMOVE( alname ); 
 END; 
 $$ 
 ; 
 </code></pre>
</td>
</tr>
</tbody>
</table>



#### 6.3.2 DBMS_ASSERT

**Description**

The DBMS_ASSERT package checks and normalizes SQL syntax elements.

##### 6.3.2.1 DBMS_ASSERT.ENQUOTE_LITERAL

**Functional differences**

 - **Oracle database**
     - If a string in an argument is already enclosed in single quotation marks, it is not again enclosed in single quotation marks.
 - **PostgreSQL**
     - Even if a string in an argument is already enclosed in single quotation marks, it is again enclosed in single quotation marks.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword DBMS_ASSERT.ENQUOTE_LITERAL and identify where it is used.
 2. In the conditions of an IF statement, use LEFT and RIGHT to check the leading and trailing characters.
 3. If each result does not match a single quotation mark (E'\x27'), use ENQUOTE_LITERAL to replace it.

**Migration example**

The example below shows migration when a string is enclosed in single quotation marks.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> DBMS_OUTPUT.PUT_LINE( 
  DBMS_ASSERT.ENQUOTE_LITERAL( en_lit ) ); 
<br>
<br>
<br>
<br>
 </code></pre>
</td>

<td align="left">
<pre><code> <b>IF ( LEFT( en_lit, 1 ) = E'\x27' AND 
      RIGHT( en_lit, 1 ) = E'\x27' ) THEN 
   PERFORM DBMS_OUTPUT.PUT_LINE( en_lit ); 
 ELSE</b> 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.ENQUOTE_LITERAL( en_lit ) ); 
 <b>END IF;</b></code></pre>
</td>
</tr>
</tbody>
</table>

**Note**

----

PostgreSQL does not verify single quotation marks.

----

##### 6.3.2.2 DBMS_ASSERT.ENQUOTE_NAME

**Functional differences**

 - **Oracle database**
     - If the string in the first argument is already enclosed in double quotation marks, it is not again enclosed in double quotation marks. <br> In addition, regardless of whether there is a second argument, a string enclosed in double quotation marks is not converted from lowercase to uppercase.
 - **PostgreSQL**
     - Even if the string in the first argument is already enclosed in double quotation marks, it is again enclosed in double quotation marks. <br> However, a first argument string that is all in lowercase is not enclosed in double quotation marks. <br>In addition, if the second argument is set to TRUE or the default, it is converted from uppercase to lowercase even if it is enclosed in double quotation marks.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword DBMS_ASSERT.ENQUOTE_NAME and identify where it is used.
 2. In the conditions of an IF statement, use LEFT and RIGHT to check the leading and trailing characters.
 3. If each result does not match a double quotation mark (E'\x27'), use ENQUOTE_NAME to replace it.

**Migration example**

The example below shows migration when a string is enclosed in double quotation marks.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> DBMS_OUTPUT.PUT_LINE( 
  DBMS_ASSERT.ENQUOTE_NAME( en_nam ) ); 
<br>
<br>
<br>
<br>
  </code></pre>
</td>

<td align="left">
<pre><code> <b>IF ( LEFT( en_nam, 1 ) = E'\x22' AND 
      RIGHT( en_nam, 1 ) = E'\x22' ) THEN 
   PERFORM DBMS_OUTPUT.PUT_LINE( en_nam ); 
 ELSE</b> 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.ENQUOTE_NAME( en_nam ) ); 
 <b>END IF;</b></code></pre>
</td>
</tr>
</tbody>
</table>

##### 6.3.2.3 DBMS_ASSERT.SIMPLE_SQL_NAME

**Functional differences**

 - **Oracle database**
     - If the leading or trailing position of a string in an argument contains a space, the space is deleted before the string is evaluated.
 - **PostgreSQL**
     - If the leading or trailing position of a string in an argument contains a space, the string is evaluated as is, causing an error.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword DBMS_ASSERT.SIMPLE_SQL_NAME and identify where it is used.
 2. If the leading or trailing position of a string in an argument contains a space, use TRIM to delete the space immediately preceding or following the argument string.

**Migration example**

The example below shows migration when the leading or trailing position of a string in an argument contains a space.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code>DBMS_OUTPUT.PUT_LINE( 
  DBMS_ASSERT.SIMPLE_SQL_NAME( si_nam ) ); 
  </code></pre>
</td>

<td align="left">
<pre><code> PERFORM DBMS_OUTPUT.PUT_LINE( 
  DBMS_ASSERT.SIMPLE_SQL_NAME( 
   <b>TRIM( both from si_nam )</b> ) );</code></pre>
</td>
</tr>
</tbody>
</table>

**See**

----

The strings checked by DBMS_ASSERT.SIMPLE_SQL_NAME correspond to identifiers among the SQL elements. Refer to "The SQL Language" > "Lexical Structure" > "Identifiers and Key Words" in the PostgreSQL Documentation for information on the values that can be used as identifiers in PostgreSQL.

----

##### 6.3.2.4 DBMS_ASSERT.SQL_OBJECT_NAME
**Functional differences**

 - **Oracle database**
     - DBMS_ASSERT.SQL_OBJECT_NAME exists.
 - **PostgreSQL**
     - DBMS_ASSERT.SQL_OBJECT_NAME does not exist. Use DBMS_ASSERT.OBJECT_NAME instead.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword DBMS_ASSERT.SQL_OBJECT_NAME and identify where it is used.
 2. Change DBMS_ASSERT.SQL_OBJECT_NAME to DBMS_ASSERT.OBJECT_NAME.

**Migration example**

The example below shows migration when an input value is verified as a qualified SQL identifier of an existing SQL object.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SELECT 
   DBMS_ASSERT.<b>SQL_OBJECT_NAME</b>( 'inventory_table' ) 
  INTO table_name 
  FROM DUAL;</code></pre>
</td>

<td align="left">
<pre><code> SELECT 
   DBMS_ASSERT.<b>OBJECT_NAME</b>( 'inventory_table' ) 
  INTO table_name 
  FROM DUAL;</code></pre>
</td>
</tr>
</tbody>
</table>


##### 6.3.2.5 Example of Migrating DBMS_ASSERT
The example below shows migration to PL/pgSQL when DBMS_ASSERT is used.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SET SERVEROUTPUT ON 
 DECLARE 
  en_lit VARCHAR2(50) := '''ENQUOTE_LITERAL'''; 
  en_nam VARCHAR2(50) := '"enquote_name"'; 
  si_nam VARCHAR2(50) := ' SIMPLE_SQL_NAME   '; 
  table_name VARCHAR2(20); 
 BEGIN 
<br>
  DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.ENQUOTE_LITERAL( en_lit )); 
<br>
<br>
<br>
<br>
<br>
<br>
  DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.ENQUOTE_NAME( en_nam )); 
<br>
<br>
<br>
<br>
<br>
<br>
  DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.SIMPLE_SQL_NAME( si_nam )); 
<br>
<br>
  SELECT DBMS_ASSERT.<b>SQL_OBJECT_NAME</b>( 
                     'inventory_table' ) 
  INTO table_name 
  FROM DUAL; 
  DBMS_OUTPUT.PUT_LINE( 
              'Object is : ' &#124;&#124; table_name ); 
 END; 
 / 
 </code></pre>
</td>

<td align="left">
<pre><code> DO $$ 
 DECLARE 
  en_lit VARCHAR2(50) := '''ENQUOTE_LITERAL''';  
  en_nam VARCHAR2(50) := '"enquote_name"';  
  si_nam VARCHAR2(50) := ' SIMPLE_SQL_NAME   ';  
  table_name VARCHAR2(20);  
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT(TRUE);  
  <b>IF ( LEFT( en_lit, 1 ) = E'\x27' AND 
       RIGHT( en_lit, 1 ) = E'\x27' ) THEN 
   PERFORM DBMS_OUTPUT.PUT_LINE( en_lit );  
  ELSE</b> 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
    DBMS_ASSERT.ENQUOTE_LITERAL( en_lit )); 
  <b>END IF;</b> 
<br>
  <b>IF ( LEFT( en_nam, 1 ) = E'\x22' AND 
       RIGHT( en_nam, 1 ) = E'\x22' ) THEN 
   PERFORM DBMS_OUTPUT.PUT_LINE( en_nam ); 
  ELSE</b> 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
    DBMS_ASSERT.ENQUOTE_NAME( en_nam ) ); 
  <b>END IF; </b> 
<br>
  PERFORM DBMS_OUTPUT.PUT_LINE( 
   DBMS_ASSERT.SIMPLE_SQL_NAME( 
                       <b>TRIM( both from si_nam ) ) );</b> 
<br>
  SELECT DBMS_ASSERT.<b>OBJECT_NAME</b>( 
                     'inventory_table' ) 
   INTO table_name 
   FROM DUAL; 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
                      'Object is : ' &#124;&#124; table_name ); 
 END; 
 $$ 
 ;  </code></pre>
</td>
</tr>
</tbody>
</table>

#### 6.3.3 DBMS_OUTPUT
**Description**

The DBMS_OUTPUT package sends messages from PL/pgSQL to clients such as psql.

##### 6.3.3.1 Differences in the Timing of Output Immediately After DBMS_OUTPUT.SERVEROUTPUT Changes from OFF to ON

**Functional differences**

 - **Oracle database**
     - Messages stored in the buffer while SERVEROUTPUT is OFF are displayed after the execution of the first SQL statement or anonymous PL/SQL after SERVEROUTPUT changes to ON.
 - **PostgreSQL**
     - Messages stored in the buffer while SERVEROUTPUT is FALSE are not displayed even after the execution of the first SQL statement or anonymous block after SERVEROUTPUT changes to TRUE. DBMS_OUT.NEW_LINE must be executed.

**Migration procedure**

Use the following procedure to perform migration:
 1. Search for the keyword SERVEROUTPUT and identify where it changes from OFF to ON.
 2. Change the code so that DBMS_OUT.NEW_LINE is executed immediately after the SQL statement or anonymous block that is executed after the SERVEROUTPUT statement is changed to ON.

**Migration example**

The example below shows migration when the status of SERVEROUTPUT changes.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SET SERVEROUTPUT OFF; 
<br>
<br>
<br>
<br>
<br>
 ... 
<br>
 <b>SET SERVEROUTPUT ON;</b> 
 SELECT * FROM dual; 
<br>
<br>
<br>
<br>
<br>
 </code></pre>
</td>

<td align="left">
<pre><code> DO $$ 
 BEGIN 
 PERFORM DBMS_OUTPUT.SERVEROUTPUT( FALSE ); 
 END; 
 $$ 
 ; 
 ... 
<br>
 SELECT * FROM dual; 
 <b>DO $$ 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE );  
  PERFORM DBMS_OUTPUT.NEW_LINE(); 
 END; 
 $$ 
 ;</b> 
 </code></pre>
</td>
</tr>
</tbody>
</table>

##### 6.3.3.2 Other Notes on Using DBMS_OUTPUT

This section explains the functional differences to be noted when DBMS_OUTPUT is used. Note that PL/pgSQL features cannot migrate these functional differences. Consider, for example, changing the application logic.

###### 6.3.3.2.1 Differences in the Output Timing of DBMS_OUTPUT.PUT_LINE and DBMS_OUTPUT.NEW_LINE

**Functional differences**

 - **Oracle database**
     - When SERVEROUTPUT is ON, the outputs of DBMS_OUTPUT.PUT_LINE and DBMS_OUTPUT.NEW_LINE are displayed together after the procedure finishes. <br> These outputs are stored in the buffer of the server while the procedure is running.
 - **PostgreSQL**
     - When SERVEROUTPUT is TRUE, the outputs from executing DBMS_OUTPUT.PUT_LINE and DBMS_OUTPUT.NEW_LINE are sent to the client and displayed immediately. <br> They are not stored in the buffer of the server.

##### 6.3.3.3 Example of Migrating DBMS_OUTPUT
The example below shows migration to PL/pgSQL when DBMS_OUTPUT is used.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SET SERVEROUTPUT OFF; 
 BEGIN 
<br>
  DBMS_OUTPUT.ENABLE( NULL ); 
  DBMS_OUTPUT.PUT_LINE( '1:Hello World' ); 
 END; 
 / 
<br>
 <b>SET SERVEROUTPUT ON</b> 
 SELECT * FROM dual; 
<br>
<br>
<br>
<br>
<br>
<br>
 </code></pre>
</td>

<td align="left">
<pre><code> DO $$ 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( FALSE ); 
  PERFORM DBMS_OUTPUT.ENABLE( NULL ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( '1:Hello World' ); 
 END; 
 $$ 
 ; 
 SELECT * FROM dual; 
 <b>DO $$ 
  BEGIN 
   PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
   PERFORM DBMS_OUTPUT.NEW_LINE(); 
 END; 
 $$ 
 ;</b> </code></pre>
</td>
</tr>
</tbody>
</table>

#### 6.3.4 DBMS_PIPE
**Description**

The DBMS_PIPE package performs one-to-one communication between PL/pgSQL sessions.

##### 6.3.4.1 Differences from the DBMS_PIPE.CREATE_PIPE Definition
**Functional differences**

 - **Oracle database**
     - The second argument specifies the maximum size of the pipe in bytes. The default is 8192 bytes. <br> The third argument specifies the pipe type. The default is TRUE (private pipe).
 - **PostgreSQL**
     - The second argument specifies the maximum number of messages that the pipe can hold. The default is 0. The specifiable range of numeric values is 1 to 32767. <br> The third argument specifies the pipe type. The default is FALSE (public pipe).

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword DBMS_PIPE.CREATE_PIPE and identify where it is used.
 2. Change the code so that the maximum number of messages is specified in the second argument.
 3. If the third argument is omitted and a private pipe is to be created, specify TRUE in the third argument.

**Note**

----

Preferably, create a public pipe (the default) as the pipe type. If you create a private pipe, internal information (the creator of the private pipe) will remain even after the pipe is removed. Thus repeatedly creating and removing pipes may ultimately cause memory to run out.

----

**Migration example**

The example below shows migration of DBMS_PIPE.CREATE_PIPE.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> DBMS_PIPE.CREATE_PIPE( 
           'pipename', 
           <b>2000,  
           TRUE</b> );</code></pre>
</td>

<td align="left">
<pre><code> DBMS_PIPE.CREATE_PIPE( 
           'pipename', 
           <b>50, 
           TRUE</b> );</code></pre>
</td>
</tr>
</tbody>
</table>

##### 6.3.4.2 Return Values of DBMS_PIPE.CREATE_PIPE and DBMS_PIPE.REMOVE_PIPE
**Functional differences**

 - **Oracle database**
     - DBMS_PIPE.CREATE_PIPE and DBMS_PIPE.REMOVE_PIPE both return values.
 - **PostgreSQL**
     - DBMS_PIPE.CREATE_PIPE and DBMS_PIPE.REMOVE_PIPE both do not return values.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keywords DBMS_PIPE.CREATE_PIPE and DBMS_PIPE.REMOVE_PIPE, and identify where they are used.
 2. Change the code so that the call processing identified in step 1 is called by the PERFORM keyword.
 3. If return values are used, replace the target processing with 0.

**Migration example**

The example below shows migration of DBMS_PIPE.CREATE_PIPE.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> <b>st := DBMS_PIPE.CREATE_PIPE( pipename, 2000 );</b> 
 DBMS_OUTPUT.PUT_LINE( 'Return Value =' &#124;&#124; st ); 
<br>
 </code></pre>
</td>

<td align="left">
<pre><code> <b>PERFORM DBMS_PIPE.CREATE_PIPE( pipename, 50 ); 
 st := 0;</b> 
 PERFORM DBMS_OUTPUT.PUT_LINE( 
                  'Return Value =' &#124;&#124; st );</code></pre>
</td>
</tr>
</tbody>
</table>

##### 6.3.4.3 Creating the Same Pipe Name with DBMS_PIPE.CREATE_PIPE
**Functional differences**

 - **Oracle database**
     - If a pipe with the same name already exists and can be used, DBMS_PIPE.CREATE_PIPE returns normally.
 - **PostgreSQL**
     - If a pipe with the same name already exists, DBMS_PIPE.CREATE_PIPE returns with an error.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword CREATE_PIPE and identify where it is used.
 2. If there may be a pipe with the same name, use the PERFORM statement shown below to check if the same pipe exists.
 3. If NOT FOUND returns TRUE, there is no pipe with the same name, so execute CREATE_PIPE.

~~~
PERFORM 1
  FROM DBMS_PIPE.DB_PIPES
  WHERE NAME = nameOfPipeToBeCreated
~~~

**Migration example**

The example below shows migration of CREATE_PIPE when there may be a pipe with the same name.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code>  
 DECLARE 
  pipename VARCHAR2(1000) := 'TESTPIPE01'; 
 BEGIN 
  <b>DBMS_OUTPUT.PUT_LINE( 
   'Return = '&#124;&#124; DBMS_PIPE.CREATE_PIPE( 
                           pipename, 
                           2000, 
                           TRUE ) );</b> 
<br>
<br>
<br>
 END; 
 / 
 </code></pre>
</td>

<td align="left">
<pre><code> DO $$ 
 DECLARE 
 pipename VARCHAR2(1000) := 'TESTPIPE01'; 
 BEGIN 
  <b>PERFORM 1 
   FROM DBMS_PIPE.DB_PIPES 
   WHERE NAME = pipename;  
  IF ( NOT FOUND ) THEN 
   PERFORM DBMS_PIPE.CREATE_PIPE( pipename, 
                                  50, 
                                  TRUE ); 
 END IF;</b> 
 END; 
 $$ 
 ;</code></pre>
</td>
</tr>
</tbody>
</table>

##### 6.3.4.4 Return Values of DBMS_PIPE.NEXT_ITEM_TYPE
**Functional differences**

 - **Oracle database**
     - DBMS_PIPE.NEXT_ITEM_TYPE has the following return values: <br> 0: There is no next item. <br> 6: NUMBER type <br> 9: VARCHAR2 type <br> 11: ROWID type <br> 12: DATE type <br> 23: RAW type
 - **PostgreSQL**
     - DBMS_PIPE.NEXT_ITEM_TYPE has the following return values: <br> 0: There is no next item. <br> 9: NUMERIC type <br> 11: TEXT type <br> 12: DATE type <br> 13: TIMESTAMP type <br> 23: BYTEA type <br> 24: RECORD type

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword NEXT_ITEM_TYPE and identify the variable storing the return value of NEXT_ITEM_TYPE.
 2. If the return value of NEXT_ITEM_TYPE is determined, change it to the value in PostgreSQL according to the table below.

**Correspondence of return values of DBMS_PIPE.NEXT_ITEM_TYPE**

|Oracle database|PostgreSQL|
|:---|:---|
|	NUMBER type	|	NUMERIC type	|
|	VARCHAR2 type	|	TEXT type	|
|	ROWID type	|		|
|		|	DATE type	|
|	DATE type	|	TIMESTAMP type	|
|	RAW type	|	BYTEA type	|
|		|	RECORD type	|

**Migration example**

The example below shows migration when processing is branched according to the return value of DBMS_PIPE.NEXT_ITEM_TYPE.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> item := DBMS_PIPE.NEXT_ITEM_TYPE; 
 IF ( <b>item = 6</b> ) THEN  -- NUMBER type 
 ~ 
 ELSIF ( <b>item = 9</b> ) THEN -- VARCHAR2 type 
 ~ 
 ELSIF ( <b>item = 12</b> ) THEN  -- DATE type 
 ~</code></pre>
</td>

<td align="left">
<pre><code> item := DBMS_PIPE.NEXT_ITEM_TYPE(); 
 IF ( <b>item = 9</b> ) THEN  -- NUMERIC type 
 ~ 
 ELSIF ( <b>item =11</b> ) THEN -- TEXT type 
 ~ 
 ELSIF ( <b>item = 13</b> ) THEN -- TIMESTAMP type 
 ~</code></pre>
</td>
</tr>
</tbody>
</table>


##### 6.3.4.5 Data Types That Can be Used in DBMS_PIPE.PACK_MESSAGE and UNPACK_MESSAGE
**Functional differences**

 - **Oracle database**
     - The data types that can be used are VARCHAR2, NCHAR, NUMBER, DATE, RAW, and ROWID. <br> When RAW or ROWID is used, the data type must be specified after UNPACK_MESSAGE.
 - **PostgreSQL**
     - The data types that can be used are TEXT, NUMERIC, INTEGER (Note), BIGINT (Note), DATE, TIMESTAMP, BYTEA, and RECORD. <br> All data types require the data type and empty parentheses to be specified after UNPACK_MESSAGE.

**Note**

----

 - The INTEGER and BIGINT data types can be used with PACK_MESSAGE only.
 - The INTEGER and BIGINT types are converted internally to the NUMERIC type. Therefore, use UNPACK_MESSAGE_NUMBER to receive a message.

----

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword UNPACK_MESSAGE and identify where UNPACK_MESSAGE is used.
 2. Change the variable specified in the argument to an assignment expression specified on the left-hand side, separately specify each data type after UNPACK_MESSAGE, and delete the variable from the parentheses.

**Migration example**

The example below shows migration when a message is sent and received.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code>DBMS_PIPE.UNPACK_MESSAGE( <b>testnum</b> );</code></pre>
</td>

<td align="left">
<pre><code> <b>testnum :=</b> 
     DBMS_PIPE.UNPACK_MESSAGE_<b>NUMBER();</b></code></pre>
</td>
</tr>
</tbody>
</table>

##### 6.3.4.6 Case Sensitivity of DBMS_PIPE.RECEIVE_MESSAGE and SEND_MESSAGE
**Functional differences**

 - **Oracle database**
     - Pipe names are case-insensitive.
 - **PostgreSQL**
     - Pipe names are case-sensitive.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keywords RECEIVE_MESSAGE and SEND_MESSAGE, and check the pipe names.
 2. If there are pipe names in different cases (uppercase and lowercase characters), change them to the same case.

**Migration example**

The example below shows migration when uppercase and lowercase characters are used for the pipe names.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> (Sending side) 
 st := DBMS_PIPE.SEND_MESSAGE( <b>'TESTPIPE01'</b>, 
                               10, 
                               8192 ); 
 (Receiving side) 
 st := DBMS_PIPE.RECEIVE_MESSAGE( <b>'testpipe01'</b> );</code></pre>
</td>

<td align="left">
<pre><code> (Sending side) 
 st := DBMS_PIPE.SEND_MESSAGE( <b>'TESTPIPE01'</b>, 
                               10, 
                               100 );  
 (Receiving side) 
 st := DBMS_PIPE.RECEIVE_MESSAGE( <b>'TESTPIPE01'</b> );</code></pre>
</td>
</tr>
</tbody>
</table>


**Note**

----

The return values of DBMS_PIPE.RECEIVE_MESSAGE and DBMS_PIPE.SEND_MESSAGE differ as shown below.

 - **Oracle database**
     - There are five return values, as follows: <br> 0: Completed successfully. <br> 1: A timeout occurred. <br> 2: A record in the pipe is too big for the buffer. <br> 3: An interrupt occurred. <br> ORA-23322: The user does not have privileges for reading the pipe. 
 - **PostgreSQL**
     - There are two return values, as follows: <br> 0: Completed successfully. <br> 1: A timeout occurred.

----

##### 6.3.4.7 Differences in the DBMS_PIPE.SEND_MESSAGE Feature

**Functional differences**

 - **Oracle database**
     - The third argument specifies the maximum size of the pipe in bytes. The default is 8192 bytes.
 - **PostgreSQL**
     - The third argument specifies the maximum number of messages that the pipe can hold. <br> The specifiable range of numeric values is 1 to 32767. <br> Note that if the maximum number of messages is omitted for an implicit pipe, the number is unlimited.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keyword SEND_MESSAGE and identify where the maximum number of bytes is specified.
 2. Replace the maximum number of bytes with the maximum number of messages.

**Migration example**

The example below shows migration when the maximum pipe size is specified.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> DBMS_PIPE.SEND_MESSAGE( 'testPIPE', 10, <b>200</b> );</code></pre>
</td>

<td align="left">
<pre><code> DBMS_PIPE.SEND_MESSAGE( 'testPIPE', 10, <b>10</b> );</code></pre>
</td>
</tr>
</tbody>
</table>

### 6.3.4.8 Example of Migrating DBMS_PIPE
The example below shows migration when one-to-one communication is performed between PL/pgSQL sessions.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> (Sending side) 
 SET SERVEROUTPUT ON; 
 DECLARE 
  testnum NUMBER := 111; 
  testvchar2 VARCHAR2(100) := 'Test Message'; 
  testdate DATE := SYSDATE; 
  testraw RAW(100) := '0101010101'; 
  st INT; 
  pipename VARCHAR2(1000) := 'TESTPIPE01'; 
 BEGIN 
<br>
  <b>st := DBMS_PIPE.CREATE_PIPE( pipename, 2000 );</b> 
<br>
<br>
<br>
<br>
<br>
  DBMS_OUTPUT.PUT_LINE( 'Return Value =' &#124;&#124; st ); 
<br>
<br>
  DBMS_PIPE.PACK_MESSAGE( testnum ); 
  DBMS_PIPE.PACK_MESSAGE( testvchar2 ); 
  DBMS_PIPE.PACK_MESSAGE( testdate ); 
  DBMS_PIPE.PACK_MESSAGE_RAW( testraw ); 
  st := DBMS_PIPE.SEND_MESSAGE( 'TESTPIPE01', 
                                10, 
                                <b>200</b> ); 
   DBMS_OUTPUT.PUT_LINE( 'Return Value =' &#124;&#124; st ); 
<br>
 END; 
 / 
<br>
 ------------------------------------------------- 
 (Receiving side) 
 SET SERVEROUTPUT ON; 
 DECLARE 
   testnum NUMBER; 
   testvchar2 VARCHAR2(100); 
   testdate DATE; 
   testraw RAW(100); 
   item NUMBER; 
   st INT; 
 BEGIN 
<br>
  st := DBMS_PIPE.RECEIVE_MESSAGE( <b>'testpipe01'</b> ); 
  DBMS_OUTPUT.PUT_LINE( 'Return Value =' &#124;&#124; st ); 
<br>
  LOOP 
   item := DBMS_PIPE.NEXT_ITEM_TYPE; 
   DBMS_OUTPUT.PUT_LINE( 'Next Item : ' &#124;&#124; item ); 
<br>
   IF ( <b>item = 6</b> ) THEN 
    <b>DBMS_PIPE.UNPACK_MESSAGE( testnum );</b> 
<br>
   DBMS_OUTPUT.PUT_LINE( 
    'Get Message : ' &#124;&#124; testnum ); 
   ELSIF ( <b>item = 9</b> ) THEN 
    <b>DBMS_PIPE.UNPACK_MESSAGE( testvchar2 );</b> 
<br>
    DBMS_OUTPUT.PUT_LINE( 
                'Get Message : ' &#124;&#124; testvchar2 ); 
   ELSIF ( <b>item = 12</b> ) THEN 
    <b>DBMS_PIPE.UNPACK_MESSAGE( testdate );</b> 
<br>
    DBMS_OUTPUT.PUT_LINE( 
                'Get Message : ' &#124;&#124; testdate ); 
   ELSIF ( item = 23 ) THEN 
    <b>DBMS_PIPE.UNPACK_MESSAGE_RAW( testraw );</b> 
<br>
<br>
<br>
    DBMS_OUTPUT.PUT_LINE( 
                'Get Message : ' &#124;&#124; testraw ); 
   ELSE 
    EXIT; 
   END IF; 
  END LOOP; 
  st := DBMS_PIPE.REMOVE_PIPE( <b>'testpipe01'</b> ); 
<br>
  DBMS_OUTPUT.PUT_LINE( 'Return Value =' &#124;&#124; st ); 
<br>
 END; 
 / 
 </code></pre>
</td>

<td align="left">
<pre><code> (Sending side) 
 DO $$ 
 DECLARE 
  testnum NUMERIC := 111; 
  testtext VARCHAR2(100) := 'Test Message'; 
  testtime TIMESTAMP := current_timestamp; 
  testbytea BYTEA := '0101010101'; 
  st INT; 
  pipename VARCHAR2(1000) := 'TESTPIPE01'; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
  <b>PERFORM 1 
   FROM DBMS_PIPE.DB_PIPES 
    WHERE NAME = pipename;  
  IF ( NOT FOUND ) THEN 
   PERFORM DBMS_PIPE.CREATE_PIPE( pipename,50 ); 
   st := 0;</b> 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
                    'Return Value =' &#124;&#124; st ); 
  <b>END IF;</b> 
  PERFORM DBMS_PIPE.PACK_MESSAGE( testnum ); 
  PERFORM DBMS_PIPE.PACK_MESSAGE( testtext ); 
  PERFORM DBMS_PIPE.PACK_MESSAGE( testtime ); 
  PERFORM DBMS_PIPE.PACK_MESSAGE( testbytea ); 
  st := DBMS_PIPE.SEND_MESSAGE( 'TESTPIPE01', 
                                10, 
                                <b>10</b> );  
  PERFORM DBMS_OUTPUT.PUT_LINE( 
  'Return Value =' &#124;&#124; st ); 
 END; 
 $$ 
 ; 
 ------------------------------------------------- 
 (Receiving side) 
 DO $$ 
 DECLARE 
  testnum NUMERIC; 
  testtext VARCHAR2(100); 
  testtime TIMESTAMP; 
  testbytea BYTEA; 
  item INT; 
  st INT; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT( TRUE ); 
  st := DBMS_PIPE.RECEIVE_MESSAGE( <b>'TESTPIPE01'</b> ); 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
                      'Return Value ='&#124;&#124; st ); 
  LOOP 
   item := DBMS_PIPE.NEXT_ITEM_TYPE(); 
   PERFORM DBMS_OUTPUT.PUT_LINE( 
                       'Next Item : ' &#124;&#124; item ); 
   IF ( <b>item = 9</b> ) THEN 
    <b>testnum := 
     DBMS_PIPE.UNPACK_MESSAGE_NUMBER();</b> 
    PERFORM DBMS_OUTPUT.PUT_LINE( 
                        'Get Message : ' &#124;&#124; testnum ); 
   ELSIF ( <b>item =11</b> ) THEN 
    <b>testtext := 
     DBMS_PIPE.UNPACK_MESSAGE_TEXT();</b> 
    PERFORM DBMS_OUTPUT.PUT_LINE( 
                        'Get Message : ' &#124;&#124; testtext ); 
   ELSIF ( <b>item = 13</b> ) THEN 
    <b>testtime := 
     DBMS_PIPE.UNPACK_MESSAGE_TIMESTAMP();</b> 
    PERFORM DBMS_OUTPUT.PUT_LINE( 
                        'Get Message : ' &#124;&#124; testtime ); 
   ELSIF ( item = 23 ) THEN 
    <b>testbytea := 
     DBMS_PIPE.UNPACK_MESSAGE_BYTEA(); 
    testtext := CAST( testbytea 
     AS varchar2(100) );</b> 
        PERFORM DBMS_OUTPUT.PUT_LINE( 
                            'Get Message : ' &#124;&#124; testtext ); 
   ELSE 
    EXIT; 
   END IF; 
  END LOOP; 
  PERFORM DBMS_PIPE.REMOVE_PIPE( <b>'TESTPIPE01'</b> ); 
  st := 0; 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
                      'Return Value ='&#124;&#124; st ); 
 END; 
 $$ 
 ; 
 </code></pre>
</td>
</tr>
</tbody>
</table>

#### 6.3.5 UTL_FILE

**Description**

The UTL_FILE package enables PL/pgSQL to read and write text files.

##### 6.3.5.1 Appending a Newline at File Closure

**Functional differences**

 - **Oracle database**
     - If data in which no newline is specified remains in the buffer, a newline is appended after the data is output and then the file is closed.
 - **PostgreSQL**
     - If data in which no newline is specified remains in the buffer, the data is output and then the file is closed. A newline is not appended.

**Migration procedure**

Use the following procedure to perform migration:

 1. Search for the keywords UTL_FILE.FCLOSE and UTL_FILE.FCLOSE_ALL, and identify where they are used.
 2. If UTL_FILE.PUT is executed and no newline is specified during write processing before the file is closed, change the code so that UTL_FILE.NEW_LINE is executed before the file is closed.

**Migration example**

The example below shows migration when a file that does not end with a newline is closed.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> UTL_FILE.PUT(v_handle, buff); 
 UTL_FILE.FCLOSE(v_handle); 
 </code></pre>
</td>

<td align="left">
<pre><code> PERFORM UTL_FILE.PUT(v_handle, buff); 
 <b>PERFORM UTL_FILE.NEW_LINE(v_handle, 1);</b> 
 s_handle := UTL_FILE.FCLOSE(v_handle);</code></pre>
</td>
</tr>
</tbody>
</table>


##### 6.3.5.2	Processing UTL_FILE Exceptions

**Functional differences**

 - **Oracle database**
     - There are exception definitions for the UTL_FILE package. They can be used for determining exceptions in the EXCEPTION clause.
 - **PostgreSQL**
     - There are no exception definitions for the UTL_FILE package.

**Migration procedure**

There are no exception definitions for the UTL_FILE package, so if they are used for determining exceptions in the EXCEPTION clause, replace them with PostgreSQL error codes. Use the following procedure to perform migration:

 1. Search for the keyword UTL_FILE and check if an EXCEPTION clause is specified in the target PL/SQL.
 2. If a UTL_FILE exception is used, replace it with a PostgreSQL error code in accordance with the table below.

**Correspondence of UTL_FILE exceptions**

|UTL_FILE exception definition <br>(Oracle database)|Migratability|Corresponding PostgreSQL error code|
|:---|:---|:---|
|INVALID_PATH|Y|RAISE_EXCEPTION|
|INVALID_MODE|Y|RAISE_EXCEPTION|
|INVALID_FILEHANDLE|Y|RAISE_EXCEPTION|
|INVALID_OPERATION|Y|RAISE_EXCEPTION|
|READ_ERROR|N|Not generated|
|WRITE_ERROR|Y|RAISE_EXCEPTION|
|INTERNAL_ERROR|Y|INTERNAL_ERROR|
|CHARSETMISMATCH|N|Not generated|
|FILE_OPEN|N|Not generated|
|INVALID_MAXLINESIZE|Y|RAISE_EXCEPTION|
|INVALID_FILENAME|Y|INVALID PARAMETER<br>NULL VALUE NOT ALLOWED (file name is NULL)|
|ACCESS_DENIED|Y|RAISE_EXCEPTION|
|INVALID_OFFSET|N|Not generated|
|DELETE_FAILED|N|Not generated|
|RENAME_FAILED|Y|RAISE_EXCEPTION|

Y: Can be migrated

N: Cannot be migrated

**Migration example**

The example below shows migration when an error message is displayed during UTL_FILE exception processing.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> EXCEPTION 
  WHEN <b>UTL_FILE.INVALID_FILEHANDLE</b> THEN 
   v_errmsg := SQLERRM; 
   DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END;</code></pre>
</td>

<td align="left">
<pre><code> EXCEPTION 
  WHEN <b>RAISE_EXCEPTION</b> THEN 
   v_errmsg := SQLERRM;	 
   PERFORM DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END;</code></pre>
</td>
</tr>
</tbody>
</table>



##### 6.3.5.3 Other Notes on Using UTL_FILE
This section explains the functional differences to be noted when UTL_FILE is used. Note that PL/pgSQL features cannot migrate these functional differences. Consider, for example, changing the application logic.

###### 6.3.5.3.1 Differences in the Open Mode of UTL_FILE.FOPEN

**Functional differences**

 - **Oracle database**
     - The rb (read byte), wb (write byte), or ab (append byte) open mode can be specified.
 - **PostgreSQL**
     - The rb (read byte), wb (write byte), and ab (append byte) open modes cannot be specified for OPEN_MODE.

###### 6.3.5.3.2 Differences in UTL_FILE.IS_OPEN

**Functional differences**

 - **Oracle database**
     - Executing UTL_FILE.IS_OPEN after UTL_FILE.FCLOSE_ALL returns TRUE.
 - **PostgreSQL**
     - Executing UTL_FILE.IS_OPEN after UTL_FILE.FCLOSE_ALL returns FALSE.

###### 6.3.5.3.3 Timing of Write by UTL_FILE.FFLUSH

**Functional differences**

 - **Oracle database**
     - Buffered data up to the newline character is written.
 - **PostgreSQL**
     - All buffered data is written.

##### 6.3.5.4	Example of Migrating UTL_FILE

The example below shows migration to PL/pgSQL when UTL_FILE is used.

<table>
<thead>
<tr>
<th align="center">Oracle database</th>
<th align="center">PostgreSQL</th>
</tr>
</thead>
<tbody>
<tr>
<td align="left">
<pre><code> SET SERVEROUTPUT ON 
 DECLARE 
  v_handle   UTL_FILE.FILE_TYPE; 
  v_dirname  VARCHAR2(250); 
  v_filename VARCHAR2(250); 
  v_output   VARCHAR2(250); 
  v_getmsg   VARCHAR2(250); 
  v_errmsg   VARCHAR2(1000); 
  v_opcheck  BOOLEAN; 
 BEGIN 
  v_dirname := '/home/oracle'; 
  v_filename := 'sample.txt'; 
  v_output := 'HELLO WORLD!'; 
  v_handle := UTL_FILE.FOPEN(v_dirname, 
                             v_filename, 
                             'w', 
                             256); 
<br>
<br>
  UTL_FILE.PUT_LINE(v_handle, v_output); 
  UTL_FILE.FFLUSH(v_handle); 
  UTL_FILE.PUT(v_handle, v_output); 
<br>
  UTL_FILE.FCLOSE(v_handle); 
  v_handle := UTL_FILE.FOPEN(v_dirname, 
                             v_filename, 
                             'r', 
                             256); 
  UTL_FILE.GET_LINE(v_handle, v_getmsg); 
  DBMS_OUTPUT.PUT_LINE( 
   'GET_MESSAGE : ' &#124;&#124; v_getmsg); 
  UTL_FILE.FCLOSE_ALL; 
  v_opcheck := UTL_FILE.IS_OPEN(v_handle); 
  DBMS_OUTPUT.PUT_LINE(CASE 
   WHEN v_opcheck IS NULL THEN 'UNKNOWN' 
   WHEN v_opcheck THEN 'TRUE' 
   WHEN NOT v_opcheck THEN 'FALSE' 
   END); 
<br>
  BEGIN 
   UTL_FILE.PUT_LINE(v_handle, v_output); 
  EXCEPTION 
   WHEN <b>UTL_FILE.INVALID_FILEHANDLE</b> THEN 
    v_errmsg := SQLERRM; 
    DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END; 
<br>
 EXCEPTION WHEN OTHERS THEN 
  UTL_FILE.FCLOSE_ALL; 
  v_errmsg := SQLERRM; 
  DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END; 
 / 
 </code></pre>
</td>

<td align="left">
<pre><code> DO $$ 
 DECLARE 
  v_handle   UTL_FILE.FILE_TYPE; 
  v_dirname  VARCHAR2(250); 
  v_filename VARCHAR2(250); 
  v_output   VARCHAR2(250); 
  v_getmsg   VARCHAR2(250); 
  v_errmsg   VARCHAR2(1000); 
  v_opcheck  BOOLEAN; 
 BEGIN 
  PERFORM DBMS_OUTPUT.SERVEROUTPUT(TRUE); 
  PERFORM DBMS_OUTPUT.ENABLE(NULL); 
  v_dirname := '/home/pgsql'; 
  v_filename := 'sample.txt'; 
  v_output := 'HELLO WORLD!'; 
  v_handle := UTL_FILE.FOPEN(v_dirname, 
                             v_filename, 
                             'w', 
                             256); 
  PERFORM UTL_FILE.PUT_LINE(v_handle, v_output); 
  PERFORM UTL_FILE.PUT(v_handle, v_output); 
  PERFORM UTL_FILE.FFLUSH(v_handle); 
  <b>PERFORM UTL_FILE.NEW_LINE(v_handle, 1);</b> 
  <b>v_handle</b> := UTL_FILE.FCLOSE(v_handle); 
  v_handle := UTL_FILE.FOPEN(v_dirname, 
                             v_filename, 
                             'r', 
                             256); 
  v_getmsg := UTL_FILE.GET_LINE(v_handle); 
  PERFORM DBMS_OUTPUT.PUT_LINE( 
   'GET_MESSAGE : ' &#124;&#124; v_getmsg); 
  PERFORM UTL_FILE.FCLOSE_ALL(); 
  v_opcheck := UTL_FILE.IS_OPEN(v_handle); 
  PERFORM DBMS_OUTPUT.PUT_LINE(CASE 
   WHEN v_opcheck IS NULL THEN 'UNKNOWN' 
   WHEN v_opcheck THEN 'TRUE' 
   WHEN NOT v_opcheck THEN 'FALSE' 
   END); 
<br>
  BEGIN 
   PERFORM UTL_FILE.PUT_LINE(v_handle, v_output); 
  EXCEPTION 
   WHEN <b>RAISE_EXCEPTION</b> THEN 
    v_errmsg := SQLERRM; 
    PERFORM DBMS_OUTPUT.PUT_LINE(v_errmsg); 
   END; 
<br>
 EXCEPTION WHEN OTHERS THEN 
  PERFORM UTL_FILE.FCLOSE_ALL(); 
  v_errmsg := SQLERRM; 
  PERFORM DBMS_OUTPUT.PUT_LINE(v_errmsg); 
 END; 
 $$ 
 ;</code></pre>
</td>
</tr>
</tbody>
</table>