Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP
Newer
Older
100644 158 lines (124 sloc) 5.194 kb
64a4275 @tardate transfered sources collection to github
authored
1 #!/usr/bin/perl -w
2 #
3 # demonstrates/tests the use of Oracle temporary tables with DBI
4 # this was prompted by the discussion on perl.dbi.users list concerning
5 # SQL Server/ODBC temp tables "disappearing"
6 # See: http://www.nntp.perl.org/group/perl.dbi.users/2007/05/msg31390.html
7 #
8 # bottom line is that temp table behaviour with Oracle seems to work fine
9 #
10 # blogged about this at http://tardate.blogspot.com/2007/05/do-oracle-temp-tables-behave-correctly.html
11 #
12 # $Id: testOraTempTables.pl,v 1.3 2007/05/11 14:22:14 paulg Exp $
13 #
14
15 use DBI qw(:sql_types);
16 use Carp;
17
18 use strict;
19
20 # Set trace level if '-# trace_level' option is given
21 DBI->trace( shift ) if 1 < @ARGV && $ARGV[0] =~ /^-#/ && shift;
22
23 die "syntax: $0 [-# trace] sid user pass" if 3 > @ARGV;
24 my ( $sid, $user, $pass ) = @ARGV;
25
26 # Connect to database
27 print "[1st connection] connect to $sid {AutoCommit => 1}:\n";
28 my $dbh = DBI->connect( "dbi:Oracle:$sid", $user, $pass,
29 { AutoCommit => 1, RaiseError => 0, PrintError => 1 } )
30 or croak $DBI::errstr;
31
32 my $sth;
33
34 my $s1 = "create global temporary table t1 (x varchar2(10)) on commit preserve rows";
35 print "[1st connection] create global temp table: $s1\n";
36 $sth = $dbh->prepare($s1);
37 $sth->execute() or carp "$s1 creation failure\n";
38
39
40 # put some data into it
41 my $s2 = "insert into t1 values (?)";
42 print "[1st connection] insert 3 rows of data into it: $s2\n";
43 $sth = $dbh->prepare( $s2 );
44 $sth->bind_param(1, "row #1");
45 $sth->execute() or carp "$s2 failed\n";
46 $sth->execute() or carp "$s2 failed\n";
47 $sth->execute() or carp "$s2 failed\n";
48 $sth->finish;
49
50 $s2 = "select count(*) from t1";
51 print "[1st connection] should be 3 rows because we have \"on commit preserve rows\" set: $s2 = ";
52 printResults ($dbh, "$s2");
53
54 # 2nd Connection to database
55 print "[2nd connection] connect to $sid:\n";
56 my $dbh2 = DBI->connect( "dbi:Oracle:$sid", $user, $pass,
57 { AutoCommit => 1, RaiseError => 0, PrintError => 1 } )
58 or croak $DBI::errstr;
59 $s2 = "select count(*) from t1";
60 print "[2nd connection] should be 0 rows because while the table definition is shared, the data is not: $s2 = ";
61 printResults ($dbh2, "$s2");
62 print "[2nd connection] disconnect:\n";
63 $dbh2->disconnect;
64
65 print "[1st connection] disconnect:\n";
66 $dbh->disconnect;
67
68 print "[1st connection] reconnect {AutoCommit => 0}:\n";
69 $dbh = DBI->connect( "dbi:Oracle:$sid", $user, $pass,
70 { AutoCommit => 0, RaiseError => 0, PrintError => 1 } )
71 or croak $DBI::errstr;
72
73 $s2 = "select count(*) from t1";
74 print "[1st connection] should be 0 rows because this is a new session: $s2 = ";
75 printResults ($dbh, "$s2");
76
77 $s2 = "drop table t1";
78 print "[1st connection] drop the temp table: $s2\n";
79 $dbh->do( $s2 ) or carp "drop table failed\n";
80
81 # now test with AutoCommit => 0 and on commit delete rows
82 $s1 = "create global temporary table t1 (x varchar2(10)) on commit delete rows";
83 print "[1st connection] create global temp table: $s1\n";
84 $sth = $dbh->prepare($s1);
85 $sth->execute() or carp "$s1 creation failure\n";
86
87
88 # put some data into it
89 $s2 = "insert into t1 values (?)";
90 print "[1st connection] insert 3 rows of data into it: $s2\n";
91 $sth = $dbh->prepare( $s2 );
92 $sth->bind_param(1, "row #1");
93 $sth->execute() or carp "$s2 failed\n";
94 $sth->execute() or carp "$s2 failed\n";
95 $sth->execute() or carp "$s2 failed\n";
96 $sth->finish;
97
98 $s2 = "select count(*) from t1";
99 print "[1st connection] should be 3 rows because we have autocommit off and not committed yet: $s2 = ";
100 printResults ($dbh, "$s2");
101
102 $dbh->commit();
103
104 $s2 = "select count(*) from t1";
105 print "[1st connection] should be 0 rows because now we have committed: $s2 = ";
106 printResults ($dbh, "$s2");
107
108 print "[1st connection] disconnect:\n";
109 $dbh->disconnect;
110
111 print "[1st connection] reconnect {AutoCommit => 1}:\n";
112 $dbh = DBI->connect( "dbi:Oracle:$sid", $user, $pass,
113 { AutoCommit => 1, RaiseError => 0, PrintError => 1 } )
114 or croak $DBI::errstr;
115
116 # put some data into it
117 $s2 = "insert into t1 values (?)";
118 print "[1st connection] insert 3 rows of data into it: $s2\n";
119 $sth = $dbh->prepare( $s2 );
120 $sth->bind_param(1, "row #1");
121 $sth->execute() or carp "$s2 failed\n";
122 $sth->execute() or carp "$s2 failed\n";
123 $sth->execute() or carp "$s2 failed\n";
124 $sth->finish;
125
126 # should be no data because we have autocommit on and "on commit delete rows" defined
127 $s2 = "select count(*) from t1";
128 print "[1st connection] should be 0 rows because we have autocommit on and \"on commit delete rows\" defined: $s2 = ";
129 printResults ($dbh, "$s2");
130
131 print "[1st connection] disconnect:\n";
132 $dbh->disconnect;
133
134 print "[1st connection] reconnect {AutoCommit => 0}:\n";
135 $dbh = DBI->connect( "dbi:Oracle:$sid", $user, $pass,
136 { AutoCommit => 0, RaiseError => 0, PrintError => 1 } )
137 or croak $DBI::errstr;
138
139 $s2 = "drop table t1";
140 print "[1st connection] drop the temp table: $s2\n";
141 $dbh->do( $s2 ) or carp "drop table failed\n";
142
143 print "[1st connection] disconnect:\n";
144 $dbh->disconnect;
145
146
147 1;
148
149 # function to execute a query and print results
150 sub printResults {
151 my ($dbh, $sql) = @_;
152 my $rows = $dbh->selectall_arrayref( $sql ) or carp "$sql failed\n";;
153 foreach my $row (@$rows) {
154 print join(", ", map {defined $_ ? $_ : "(null)"} @$row), "\n";
155 }
156 }
157
Something went wrong with that request. Please try again.