Initial commit
This commit is contained in:
commit
b781755273
5
Gemfile
Normal file
5
Gemfile
Normal file
@ -0,0 +1,5 @@
|
|||||||
|
source 'http://rubygems.org'
|
||||||
|
|
||||||
|
gem 'allure-rspec'
|
||||||
|
gem 'ruby-oci8'
|
||||||
|
gem 'ruby-plsql-spec', :git => 'https://github.com/cheetah/ruby-plsql-spec.git'
|
63
Gemfile.lock
Normal file
63
Gemfile.lock
Normal file
@ -0,0 +1,63 @@
|
|||||||
|
GIT
|
||||||
|
remote: https://github.com/cheetah/ruby-plsql-spec.git
|
||||||
|
revision: f618c33b9c1038e37c442cc9c92924627b1d0f92
|
||||||
|
specs:
|
||||||
|
ruby-plsql-spec (0.5.1)
|
||||||
|
nokogiri (~> 1.6)
|
||||||
|
rspec (>= 2.0, < 4.0)
|
||||||
|
rspec-support (>= 3.1, < 4.0)
|
||||||
|
ruby-plsql (~> 0.5)
|
||||||
|
thor (~> 0.19.1)
|
||||||
|
|
||||||
|
GEM
|
||||||
|
remote: http://rubygems.org/
|
||||||
|
specs:
|
||||||
|
allure-rspec (2.13.3)
|
||||||
|
allure-ruby-commons (= 2.13.3)
|
||||||
|
rspec-core (~> 3.8)
|
||||||
|
allure-ruby-commons (2.13.3)
|
||||||
|
json (>= 1.8, < 3)
|
||||||
|
mime-types (~> 3.3)
|
||||||
|
require_all (>= 2, < 4)
|
||||||
|
uuid (~> 2.3)
|
||||||
|
diff-lcs (1.3)
|
||||||
|
json (2.3.0)
|
||||||
|
macaddr (1.7.2)
|
||||||
|
systemu (~> 2.6.5)
|
||||||
|
mime-types (3.3.1)
|
||||||
|
mime-types-data (~> 3.2015)
|
||||||
|
mime-types-data (3.2019.1009)
|
||||||
|
mini_portile2 (2.4.0)
|
||||||
|
nokogiri (1.10.7)
|
||||||
|
mini_portile2 (~> 2.4.0)
|
||||||
|
require_all (3.0.0)
|
||||||
|
rspec (3.9.0)
|
||||||
|
rspec-core (~> 3.9.0)
|
||||||
|
rspec-expectations (~> 3.9.0)
|
||||||
|
rspec-mocks (~> 3.9.0)
|
||||||
|
rspec-core (3.9.1)
|
||||||
|
rspec-support (~> 3.9.1)
|
||||||
|
rspec-expectations (3.9.0)
|
||||||
|
diff-lcs (>= 1.2.0, < 2.0)
|
||||||
|
rspec-support (~> 3.9.0)
|
||||||
|
rspec-mocks (3.9.1)
|
||||||
|
diff-lcs (>= 1.2.0, < 2.0)
|
||||||
|
rspec-support (~> 3.9.0)
|
||||||
|
rspec-support (3.9.2)
|
||||||
|
ruby-oci8 (2.2.8)
|
||||||
|
ruby-plsql (0.7.1)
|
||||||
|
systemu (2.6.5)
|
||||||
|
thor (0.19.4)
|
||||||
|
uuid (2.3.9)
|
||||||
|
macaddr (~> 1.0)
|
||||||
|
|
||||||
|
PLATFORMS
|
||||||
|
ruby
|
||||||
|
|
||||||
|
DEPENDENCIES
|
||||||
|
allure-rspec
|
||||||
|
ruby-oci8
|
||||||
|
ruby-plsql-spec!
|
||||||
|
|
||||||
|
BUNDLED WITH
|
||||||
|
1.17.2
|
29
source/award_bonus.rb
Normal file
29
source/award_bonus.rb
Normal file
@ -0,0 +1,29 @@
|
|||||||
|
# example from SQL Developer 2.1 tutorial
|
||||||
|
# http://www.oracle.com/technology/obe/11gr2_db_prod/appdev/sqldev/sqldev_unit_test/sqldev_unit_test.htm
|
||||||
|
|
||||||
|
# Uncomment to create table employees2 which is used by award_bonus procedure
|
||||||
|
# plsql.execute "DROP TABLE employees2" rescue nil
|
||||||
|
# plsql.execute "CREATE TABLE employees2 AS SELECT * FROM employees WHERE ROWNUM < 0"
|
||||||
|
# plsql.execute "DROP SEQUENCE employees2_seq" rescue nil
|
||||||
|
# plsql.execute "CREATE SEQUENCE employees2_seq"
|
||||||
|
|
||||||
|
plsql.execute <<-SQL
|
||||||
|
CREATE OR REPLACE
|
||||||
|
PROCEDURE award_bonus (
|
||||||
|
emp_id NUMBER, sales_amt NUMBER) AS
|
||||||
|
commission REAL;
|
||||||
|
comm_missing EXCEPTION;
|
||||||
|
BEGIN
|
||||||
|
SELECT commission_pct INTO commission
|
||||||
|
FROM employees2
|
||||||
|
WHERE employee_id = emp_id;
|
||||||
|
|
||||||
|
IF commission IS NULL THEN
|
||||||
|
RAISE comm_missing;
|
||||||
|
ELSE
|
||||||
|
UPDATE employees2
|
||||||
|
SET salary = NVL(salary,0) + sales_amt*commission
|
||||||
|
WHERE employee_id = emp_id;
|
||||||
|
END IF;
|
||||||
|
END;
|
||||||
|
SQL
|
19
source/betwnstr.rb
Normal file
19
source/betwnstr.rb
Normal file
@ -0,0 +1,19 @@
|
|||||||
|
# example from utPLSQL project (http://utplsql.sourceforge.net/)
|
||||||
|
plsql.execute <<-SQL
|
||||||
|
CREATE OR REPLACE FUNCTION betwnstr (
|
||||||
|
string_in IN VARCHAR2,
|
||||||
|
start_in IN INTEGER,
|
||||||
|
end_in IN INTEGER
|
||||||
|
)
|
||||||
|
RETURN VARCHAR2
|
||||||
|
IS
|
||||||
|
l_start PLS_INTEGER := start_in;
|
||||||
|
BEGIN
|
||||||
|
IF l_start = 0
|
||||||
|
THEN
|
||||||
|
l_start := 1;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
RETURN (SUBSTR (string_in, l_start, end_in - l_start + 1));
|
||||||
|
END;
|
||||||
|
SQL
|
45
source/remove_rooms_by_name.rb
Normal file
45
source/remove_rooms_by_name.rb
Normal file
@ -0,0 +1,45 @@
|
|||||||
|
# example from Code Tester for Oracle tutorial
|
||||||
|
# http://www.quest.com/code-tester-for-oracle/product-demo/chap02.htm
|
||||||
|
|
||||||
|
# Setup test tables
|
||||||
|
plsql.execute "DROP TABLE room_contents" rescue nil
|
||||||
|
plsql.execute "DROP TABLE rooms" rescue nil
|
||||||
|
|
||||||
|
plsql.execute <<-SQL
|
||||||
|
CREATE TABLE rooms (
|
||||||
|
room_key NUMBER PRIMARY KEY,
|
||||||
|
name VARCHAR2(100)
|
||||||
|
)
|
||||||
|
SQL
|
||||||
|
plsql.execute <<-SQL
|
||||||
|
CREATE TABLE room_contents (
|
||||||
|
contents_key NUMBER PRIMARY KEY,
|
||||||
|
room_key NUMBER,
|
||||||
|
name VARCHAR2(100)
|
||||||
|
)
|
||||||
|
SQL
|
||||||
|
|
||||||
|
# Foreign key to rooms. Note: this is not a CASCADE DELETE
|
||||||
|
# key. Child data is NOT removed when the parent is
|
||||||
|
# removed.
|
||||||
|
|
||||||
|
plsql.execute <<-SQL
|
||||||
|
ALTER TABLE room_contents ADD CONSTRAINT
|
||||||
|
fk_rooms FOREIGN KEY (room_key)
|
||||||
|
REFERENCES rooms (room_key)
|
||||||
|
SQL
|
||||||
|
|
||||||
|
plsql.execute <<-SQL
|
||||||
|
CREATE OR REPLACE PROCEDURE remove_rooms_by_name (
|
||||||
|
name_in IN rooms.name%TYPE)
|
||||||
|
IS
|
||||||
|
BEGIN
|
||||||
|
IF NAME_IN IS NULL
|
||||||
|
THEN
|
||||||
|
RAISE PROGRAM_ERROR;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
DELETE FROM rooms WHERE name LIKE name_in;
|
||||||
|
|
||||||
|
END;
|
||||||
|
SQL
|
207
source/what_is_profiled.rb
Normal file
207
source/what_is_profiled.rb
Normal file
@ -0,0 +1,207 @@
|
|||||||
|
plsql.execute <<-SQL
|
||||||
|
CREATE OR REPLACE PACKAGE what_is_profiled
|
||||||
|
IS
|
||||||
|
TYPE aa1 IS TABLE OF VARCHAR2 (100)
|
||||||
|
INDEX BY PLS_INTEGER;
|
||||||
|
TYPE aa2 IS TABLE OF VARCHAR2 (100)
|
||||||
|
INDEX BY PLS_INTEGER;
|
||||||
|
PROCEDURE proc1 (arg IN NUMBER, arg2 OUT VARCHAR2);
|
||||||
|
FUNCTION func1
|
||||||
|
RETURN VARCHAR2;
|
||||||
|
|
||||||
|
procedure driver ;
|
||||||
|
END what_is_profiled;
|
||||||
|
SQL
|
||||||
|
|
||||||
|
plsql.execute <<-SQL
|
||||||
|
CREATE OR REPLACE PACKAGE BODY what_is_profiled
|
||||||
|
IS
|
||||||
|
TYPE p_aa1 IS TABLE OF VARCHAR2 (100)
|
||||||
|
INDEX BY PLS_INTEGER;
|
||||||
|
|
||||||
|
TYPE p_aa2 IS TABLE OF VARCHAR2 (100)
|
||||||
|
INDEX BY PLS_INTEGER;
|
||||||
|
|
||||||
|
PROCEDURE loops (arg IN NUMBER, arg2 OUT VARCHAR2)
|
||||||
|
IS
|
||||||
|
val
|
||||||
|
INTEGER;
|
||||||
|
condition1 boolean := true;
|
||||||
|
condition2 boolean
|
||||||
|
:=
|
||||||
|
true;
|
||||||
|
|
||||||
|
BEGIN
|
||||||
|
FOR indx IN 1 .. 100
|
||||||
|
LOOP
|
||||||
|
NULL;
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
FOR
|
||||||
|
indx
|
||||||
|
IN
|
||||||
|
1
|
||||||
|
..
|
||||||
|
100
|
||||||
|
LOOP
|
||||||
|
val := 1;
|
||||||
|
END
|
||||||
|
LOOP;
|
||||||
|
|
||||||
|
FOR indx IN 1 .. 100 LOOP NULL; END LOOP;
|
||||||
|
|
||||||
|
FOR rec IN (SELECT *
|
||||||
|
FROM all_source
|
||||||
|
WHERE ROWNUM < 101)
|
||||||
|
LOOP
|
||||||
|
val := 1;
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
FOR
|
||||||
|
rec
|
||||||
|
IN
|
||||||
|
(
|
||||||
|
SELECT *
|
||||||
|
FROM all_source
|
||||||
|
WHERE ROWNUM < 101
|
||||||
|
)
|
||||||
|
LOOP
|
||||||
|
val := 1;
|
||||||
|
END
|
||||||
|
LOOP;
|
||||||
|
|
||||||
|
WHILE (condition1 AND condition2)
|
||||||
|
LOOP
|
||||||
|
condition1 := FALSE;
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
WHILE
|
||||||
|
(
|
||||||
|
condition1
|
||||||
|
AND
|
||||||
|
condition2
|
||||||
|
)
|
||||||
|
LOOP
|
||||||
|
condition1
|
||||||
|
:=
|
||||||
|
FALSE
|
||||||
|
;
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
DECLARE
|
||||||
|
indx INTEGER := 1;
|
||||||
|
BEGIN
|
||||||
|
LOOP
|
||||||
|
EXIT WHEN indx > 100;
|
||||||
|
indx := indx + 1;
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
|
||||||
|
DECLARE
|
||||||
|
indx INTEGER := 1;
|
||||||
|
BEGIN
|
||||||
|
LOOP
|
||||||
|
EXIT
|
||||||
|
WHEN
|
||||||
|
indx
|
||||||
|
>
|
||||||
|
100;
|
||||||
|
indx := indx +
|
||||||
|
1
|
||||||
|
;
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
END;
|
||||||
|
|
||||||
|
PROCEDURE conditionals
|
||||||
|
IS
|
||||||
|
a
|
||||||
|
boolean;
|
||||||
|
b boolean;
|
||||||
|
c boolean
|
||||||
|
;
|
||||||
|
BEGIN
|
||||||
|
IF (a AND b OR c)
|
||||||
|
THEN
|
||||||
|
NULL;
|
||||||
|
elsif
|
||||||
|
a
|
||||||
|
then
|
||||||
|
null;
|
||||||
|
else
|
||||||
|
dbms_output.put_line ('a');
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
a := case
|
||||||
|
true
|
||||||
|
when true
|
||||||
|
then
|
||||||
|
false
|
||||||
|
when
|
||||||
|
false then
|
||||||
|
true
|
||||||
|
else
|
||||||
|
false
|
||||||
|
end
|
||||||
|
;
|
||||||
|
a := case true
|
||||||
|
when true
|
||||||
|
then
|
||||||
|
false
|
||||||
|
when
|
||||||
|
false then
|
||||||
|
true
|
||||||
|
else
|
||||||
|
false
|
||||||
|
end
|
||||||
|
;
|
||||||
|
|
||||||
|
case when
|
||||||
|
sysdate > sysdate + 1
|
||||||
|
then
|
||||||
|
a := false;
|
||||||
|
when 1 > 2 then
|
||||||
|
b := false;
|
||||||
|
when 1
|
||||||
|
> 2
|
||||||
|
then
|
||||||
|
c := false;
|
||||||
|
else null; end case;
|
||||||
|
END;
|
||||||
|
|
||||||
|
FUNCTION p_func1
|
||||||
|
RETURN VARCHAR2
|
||||||
|
IS
|
||||||
|
BEGIN
|
||||||
|
RETURN NULL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
PROCEDURE proc1 (arg IN NUMBER, arg2 OUT VARCHAR2)
|
||||||
|
IS
|
||||||
|
BEGIN
|
||||||
|
NULL;
|
||||||
|
END;
|
||||||
|
|
||||||
|
FUNCTION func1
|
||||||
|
RETURN VARCHAR2
|
||||||
|
IS
|
||||||
|
BEGIN
|
||||||
|
RETURN p_func1;
|
||||||
|
END;
|
||||||
|
|
||||||
|
procedure driver is
|
||||||
|
l varchar2(100);
|
||||||
|
begin
|
||||||
|
loops(1, l);
|
||||||
|
conditionals;
|
||||||
|
proc1
|
||||||
|
(
|
||||||
|
1
|
||||||
|
,
|
||||||
|
l);
|
||||||
|
GOTO checkloop;
|
||||||
|
<<checkloop>>
|
||||||
|
dbms_output.put_line ('a');
|
||||||
|
end;
|
||||||
|
END what_is_profiled;
|
||||||
|
SQL
|
33
spec/award_bonus_spec.rb
Normal file
33
spec/award_bonus_spec.rb
Normal file
@ -0,0 +1,33 @@
|
|||||||
|
# load 'award_bonus' procedure into the database
|
||||||
|
require 'award_bonus'
|
||||||
|
|
||||||
|
describe "Award bonus" do
|
||||||
|
include EmployeeFactory
|
||||||
|
|
||||||
|
[ [1000, 1234.55, 0.10, 1123.46],
|
||||||
|
[nil, 1234.56, 0.10, 123.46],
|
||||||
|
[1000, 1234.54, 0.10, 1123.45]
|
||||||
|
].each do |salary, sales_amt, commission_pct, result|
|
||||||
|
it "should calculate base salary #{salary.inspect} + sales amount #{sales_amt} * commission percentage #{commission_pct} = salary #{result.inspect}" do
|
||||||
|
employee = create_employee(
|
||||||
|
:commission_pct => commission_pct,
|
||||||
|
:salary => salary
|
||||||
|
)
|
||||||
|
plsql.award_bonus(employee[:employee_id], sales_amt)
|
||||||
|
expect(get_employee(employee[:employee_id])[:salary]).to eq result
|
||||||
|
end
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should raise ORA-06510 exception if commission percentage is missing" do
|
||||||
|
salary, sales_amt, commission_pct = 1000, 1234.55, NULL
|
||||||
|
employee = create_employee(
|
||||||
|
:commission_pct => commission_pct,
|
||||||
|
:salary => salary
|
||||||
|
)
|
||||||
|
expect {
|
||||||
|
plsql.award_bonus(employee[:employee_id], sales_amt)
|
||||||
|
}.to raise_error(/ORA-06510/)
|
||||||
|
end
|
||||||
|
|
||||||
|
end
|
||||||
|
|
22
spec/betwnstr_spec.rb
Normal file
22
spec/betwnstr_spec.rb
Normal file
@ -0,0 +1,22 @@
|
|||||||
|
# load 'betwnstr' procedure into the database
|
||||||
|
require "betwnstr"
|
||||||
|
|
||||||
|
describe "Between string" do
|
||||||
|
it "should be correct in normal case" do
|
||||||
|
expect(plsql.betwnstr('abcdefg', 2, 5)).to eq 'bcde'
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should be correct with zero start value" do
|
||||||
|
expect(plsql.betwnstr('abcdefg', 0, 5)).to eq 'abcde'
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should be correct with way big end value" do
|
||||||
|
expect(plsql.betwnstr('abcdefg', 5, 500)).to eq 'efg'
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should be correct with NULL string" do
|
||||||
|
expect(plsql.betwnstr(NULL, 5, 500)).to eq NULL
|
||||||
|
end
|
||||||
|
|
||||||
|
end
|
||||||
|
|
16
spec/database.yml
Normal file
16
spec/database.yml
Normal file
@ -0,0 +1,16 @@
|
|||||||
|
# Change default connection username, password and database.
|
||||||
|
# Specify also host and port if not using tnsnames.ora connection.
|
||||||
|
default:
|
||||||
|
username: system
|
||||||
|
password: oracle
|
||||||
|
database: xe
|
||||||
|
host: localhose
|
||||||
|
port: 1521
|
||||||
|
|
||||||
|
# Add other connection if needed.
|
||||||
|
# You can access them with plsql(:other) where :other is connection name specified below.
|
||||||
|
|
||||||
|
# other:
|
||||||
|
# username: scott
|
||||||
|
# password: tiger
|
||||||
|
# database: xe
|
23
spec/factories/employee_factory.rb
Normal file
23
spec/factories/employee_factory.rb
Normal file
@ -0,0 +1,23 @@
|
|||||||
|
module EmployeeFactory
|
||||||
|
# Creates new employee with valid field values.
|
||||||
|
# Pass in parameters only field values that you want to override.
|
||||||
|
def create_employee(params)
|
||||||
|
employee = {
|
||||||
|
:employee_id => plsql.employees2_seq.nextval,
|
||||||
|
:last_name => 'Last',
|
||||||
|
:email => 'last@example.com',
|
||||||
|
:hire_date => Date.today,
|
||||||
|
:job_id => plsql.jobs.first[:job_id],
|
||||||
|
:commission_pct => nil,
|
||||||
|
:salary => nil
|
||||||
|
}.merge(params)
|
||||||
|
plsql.employees2.insert employee
|
||||||
|
get_employee employee[:employee_id]
|
||||||
|
end
|
||||||
|
|
||||||
|
# Select employee by primary key
|
||||||
|
def get_employee(employee_id)
|
||||||
|
plsql.employees2.first :employee_id => employee_id
|
||||||
|
end
|
||||||
|
|
||||||
|
end
|
17
spec/helpers/inspect_helpers.rb
Normal file
17
spec/helpers/inspect_helpers.rb
Normal file
@ -0,0 +1,17 @@
|
|||||||
|
# As ruby-plsql returns NUMBER values as BigDecimal values in Ruby then
|
||||||
|
# change format how they are by default displayed
|
||||||
|
BigDecimal.class_eval do
|
||||||
|
def inspect
|
||||||
|
to_s('F')
|
||||||
|
end
|
||||||
|
end
|
||||||
|
|
||||||
|
# As ruby-plsql returns NULL as Ruby nil then change nil.inspect to return 'NULL'
|
||||||
|
NilClass.class_eval do
|
||||||
|
def inspect
|
||||||
|
'NULL'
|
||||||
|
end
|
||||||
|
end
|
||||||
|
|
||||||
|
# NULL looks more like SQL NULL than nil
|
||||||
|
NULL = nil
|
32
spec/helpers/oracle_ebs_helpers.rb
Normal file
32
spec/helpers/oracle_ebs_helpers.rb
Normal file
@ -0,0 +1,32 @@
|
|||||||
|
# initialize Oracle E-Business Suite session with specified user and responsibility
|
||||||
|
def init_ebs_user(params={})
|
||||||
|
# replace with default user name and responsibility and then it will not be necessary
|
||||||
|
# to specify default value as parameter
|
||||||
|
params = {
|
||||||
|
:user_name => "default user name",
|
||||||
|
:responsibility_name => "default responsibility"
|
||||||
|
}.merge(params)
|
||||||
|
|
||||||
|
row = plsql.select(:first, "SELECT usr.user_name, res.responsibility_name, usr.user_id,
|
||||||
|
urg.responsibility_id, urg.responsibility_application_id resp_appl_id
|
||||||
|
FROM apps.fnd_user_resp_groups urg,
|
||||||
|
applsys.fnd_user usr,
|
||||||
|
fnd_responsibility_vl res
|
||||||
|
WHERE usr.user_name = :user_name
|
||||||
|
AND res.responsibility_name = :responsibility_name
|
||||||
|
AND urg.user_id = usr.user_id
|
||||||
|
AND res.responsibility_id = urg.responsibility_id",
|
||||||
|
params[:user_name], params[:responsibility_name])
|
||||||
|
|
||||||
|
raise ArgumentError, "Wrong user name or responsibility name" unless row
|
||||||
|
|
||||||
|
plsql.fnd_global.apps_initialize(
|
||||||
|
:user_id => row[:user_id],
|
||||||
|
:resp_id => row[:responsibility_id],
|
||||||
|
:resp_appl_id => row[:resp_appl_id]
|
||||||
|
)
|
||||||
|
|
||||||
|
# uncomment if logging to dbms_output is necessary
|
||||||
|
# plsql.dbms_output.put_line("Initialized " + params[:user_name] + " / " + params[:responsibility_name])
|
||||||
|
|
||||||
|
end
|
5
spec/helpers/time_helpers.rb
Normal file
5
spec/helpers/time_helpers.rb
Normal file
@ -0,0 +1,5 @@
|
|||||||
|
# return current date with time 00:00:00
|
||||||
|
def Time.today
|
||||||
|
t = Time.now
|
||||||
|
Time.local(t.year, t.month, t.day)
|
||||||
|
end unless Time.respond_to?(:today)
|
59
spec/oracle_ebs_spec.rb
Normal file
59
spec/oracle_ebs_spec.rb
Normal file
@ -0,0 +1,59 @@
|
|||||||
|
describe "Oracle E-Business Suite" do
|
||||||
|
before(:all) do
|
||||||
|
# @old_connection = plsql.connection
|
||||||
|
# plsql.connect! "APPS", "APPS", "VIS"
|
||||||
|
@user_name = "OPERATIONS"
|
||||||
|
@responsibility_name = "System Administrator"
|
||||||
|
end
|
||||||
|
|
||||||
|
after(:all) do
|
||||||
|
# plsql.connection = @old_connection
|
||||||
|
end
|
||||||
|
|
||||||
|
if plsql.schema_name == 'APPS'
|
||||||
|
|
||||||
|
describe "Session initialization" do
|
||||||
|
it "should initialize session with valid user and responsibility" do
|
||||||
|
expect {
|
||||||
|
init_ebs_user(:user_name => @user_name, :responsibility_name => @responsibility_name)
|
||||||
|
}.not_to raise_error
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should raise error with invalid user" do
|
||||||
|
expect {
|
||||||
|
init_ebs_user(:user_name => "INVALID", :responsibility_name => @responsibility_name)
|
||||||
|
}.to raise_error(/Wrong user name or responsibility name/)
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should raise error with invalid responsibility" do
|
||||||
|
expect {
|
||||||
|
init_ebs_user(:user_name => @user_name, :responsibility_name => "INVALID")
|
||||||
|
}.to raise_error(/Wrong user name or responsibility name/)
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should raise error with default username and responsibility parameters" do
|
||||||
|
expect {
|
||||||
|
init_ebs_user
|
||||||
|
}.to raise_error(/Wrong user name or responsibility name/)
|
||||||
|
end
|
||||||
|
|
||||||
|
end
|
||||||
|
|
||||||
|
describe "Session information" do
|
||||||
|
before(:all) do
|
||||||
|
init_ebs_user(:user_name => @user_name, :responsibility_name => @responsibility_name)
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should return user name" do
|
||||||
|
expect(plsql.fnd_global.user_name).to eq @user_name
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should return responsibility name" do
|
||||||
|
expect(plsql.fnd_global.resp_name).to eq @responsibility_name
|
||||||
|
end
|
||||||
|
|
||||||
|
end
|
||||||
|
|
||||||
|
end
|
||||||
|
|
||||||
|
end
|
49
spec/remove_rooms_by_name_spec.rb
Normal file
49
spec/remove_rooms_by_name_spec.rb
Normal file
@ -0,0 +1,49 @@
|
|||||||
|
require 'remove_rooms_by_name'
|
||||||
|
|
||||||
|
describe "Remove rooms by name" do
|
||||||
|
before(:all) do
|
||||||
|
plsql.rooms.insert_values(
|
||||||
|
[:room_key, :name],
|
||||||
|
[1, 'Dining Room'],
|
||||||
|
[2, 'Living Room'],
|
||||||
|
[3, 'Office'],
|
||||||
|
[4, 'Bathroom'],
|
||||||
|
[5, 'Bedroom']
|
||||||
|
)
|
||||||
|
plsql.room_contents.insert_values(
|
||||||
|
[:contents_key, :room_key, :name],
|
||||||
|
[1, 1, 'Table'],
|
||||||
|
[2, 1, 'Hutch'],
|
||||||
|
[3, 1, 'Chair'],
|
||||||
|
[4, 2, 'Sofa'],
|
||||||
|
[5, 2, 'Lamp'],
|
||||||
|
[6, 3, 'Desk'],
|
||||||
|
[7, 3, 'Chair'],
|
||||||
|
[8, 3, 'Computer'],
|
||||||
|
[9, 3, 'Whiteboard']
|
||||||
|
)
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should remove a room without furniture" do
|
||||||
|
rooms_without_b = plsql.rooms.all("WHERE name NOT LIKE 'B%'")
|
||||||
|
plsql.remove_rooms_by_name('B%')
|
||||||
|
expect(plsql.rooms.all).to eq rooms_without_b
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should not remove a room with furniture" do
|
||||||
|
expect {
|
||||||
|
expect {
|
||||||
|
plsql.remove_rooms_by_name('Living Room')
|
||||||
|
}.to raise_error(/ORA-02292/)
|
||||||
|
}.not_to change { plsql.rooms.all }
|
||||||
|
end
|
||||||
|
|
||||||
|
it "should raise exception when NULL value passed" do
|
||||||
|
expect {
|
||||||
|
expect {
|
||||||
|
plsql.remove_rooms_by_name(NULL)
|
||||||
|
}.to raise_error(/program error/)
|
||||||
|
}.not_to change { plsql.rooms.all }
|
||||||
|
end
|
||||||
|
|
||||||
|
end
|
80
spec/spec_helper.rb
Normal file
80
spec/spec_helper.rb
Normal file
@ -0,0 +1,80 @@
|
|||||||
|
require "rubygems"
|
||||||
|
require "yaml"
|
||||||
|
require "ruby-plsql-spec"
|
||||||
|
require "allure-rspec"
|
||||||
|
|
||||||
|
# create all connections specified in database.yml file
|
||||||
|
database_config_file = File.expand_path('../database.yml', __FILE__)
|
||||||
|
database_config = YAML.load(File.read(database_config_file))
|
||||||
|
database_config = {} unless database_config.is_a?(Hash)
|
||||||
|
database_connections = database_config.keys.map{|k| k.to_sym}
|
||||||
|
|
||||||
|
database_connections.each do |name|
|
||||||
|
params = database_config[name.to_s]
|
||||||
|
symbol_params = Hash[*params.map{|k,v| [k.to_sym, v]}.flatten]
|
||||||
|
|
||||||
|
plsql(name).connect! symbol_params
|
||||||
|
|
||||||
|
# Set autocommit to false so that automatic commits after each statement are _not_ performed
|
||||||
|
plsql(name).connection.autocommit = false
|
||||||
|
# reduce network traffic in case of large resultsets
|
||||||
|
plsql(name).connection.prefetch_rows = 100
|
||||||
|
# log DBMS_OUTPUT to standard output
|
||||||
|
if ENV['PLSQL_DBMS_OUTPUT']
|
||||||
|
plsql(name).dbms_output_stream = STDOUT
|
||||||
|
end
|
||||||
|
|
||||||
|
# start code coverage collection
|
||||||
|
if ENV['PLSQL_COVERAGE']
|
||||||
|
PLSQL::Coverage.start(name)
|
||||||
|
end
|
||||||
|
end
|
||||||
|
|
||||||
|
# Do logoff when exiting to ensure that session temporary tables
|
||||||
|
# (used when calling procedures with table types defined in packages)
|
||||||
|
at_exit do
|
||||||
|
database_connections.reverse_each do |name|
|
||||||
|
if ENV['PLSQL_COVERAGE']
|
||||||
|
PLSQL::Coverage.stop(name)
|
||||||
|
coverage_directory = name == :default ? ENV['PLSQL_COVERAGE'] : "#{ENV['PLSQL_COVERAGE']}/#{name}"
|
||||||
|
options = {:directory => coverage_directory}
|
||||||
|
options[:ignore_schemas] = ENV['PLSQL_COVERAGE_IGNORE_SCHEMAS'].split(',') if ENV['PLSQL_COVERAGE_IGNORE_SCHEMAS']
|
||||||
|
options[:like] = ENV['PLSQL_COVERAGE_LIKE'].split(',') if ENV['PLSQL_COVERAGE_LIKE']
|
||||||
|
PLSQL::Coverage.report name, options
|
||||||
|
PLSQL::Coverage.cleanup name
|
||||||
|
end
|
||||||
|
plsql(name).logoff
|
||||||
|
end
|
||||||
|
end
|
||||||
|
|
||||||
|
RSpec.configure do |config|
|
||||||
|
config.formatter = AllureRspecFormatter
|
||||||
|
|
||||||
|
config.before(:each) do
|
||||||
|
database_connections.each do |name|
|
||||||
|
plsql(name).savepoint "before_each"
|
||||||
|
end
|
||||||
|
end
|
||||||
|
config.after(:each) do
|
||||||
|
# Always perform rollback to savepoint after each test
|
||||||
|
database_connections.reverse_each do |name|
|
||||||
|
plsql(name).rollback_to "before_each"
|
||||||
|
end
|
||||||
|
end
|
||||||
|
config.after(:all) do
|
||||||
|
# Always perform rollback after each describe block
|
||||||
|
database_connections.reverse_each do |name|
|
||||||
|
plsql(name).rollback
|
||||||
|
end
|
||||||
|
end
|
||||||
|
end
|
||||||
|
|
||||||
|
# require all helper methods which are located in any helpers subdirectories
|
||||||
|
Dir[File.dirname(__FILE__) + '/**/helpers/*.rb'].each {|f| require f}
|
||||||
|
|
||||||
|
# require all factory modules which are located in any factories subdirectories
|
||||||
|
Dir[File.dirname(__FILE__) + '/**/factories/*.rb'].each {|f| require f}
|
||||||
|
|
||||||
|
# If necessary add source directory to load path where PL/SQL procedures are defined.
|
||||||
|
# It is not required if PL/SQL procedures are already loaded in test database in some other way.
|
||||||
|
$:.push File.dirname(__FILE__) + '/../source'
|
10
spec/what_is_profiled_spec.rb
Normal file
10
spec/what_is_profiled_spec.rb
Normal file
@ -0,0 +1,10 @@
|
|||||||
|
require 'what_is_profiled'
|
||||||
|
|
||||||
|
describe "what is profiled" do
|
||||||
|
it "should run driver" do
|
||||||
|
expect {
|
||||||
|
plsql.what_is_profiled.driver
|
||||||
|
}.not_to raise_error
|
||||||
|
end
|
||||||
|
|
||||||
|
end
|
Reference in New Issue
Block a user