Friday, 19 March 2010

Using Oracle Profile

First of all alter the system or edit the parameter file for this entry
Alter system set resource_limit = true
After that create a profile with the required options
Assign these profiles to the users whoever you want to restrict

Create profile test_profile
Limit session_per_user 2
idle_time 2 ;

Assign this profile to users

Alter user scott
Profile test_profile;

oracle 10g on OEL and RHL

Swap space configuration
Between 513 MB and 2048 MB 1.5 times the size of RAM Between 2049 MB and 8192 MB Equal to the size of RAM

check swap space
# grep SwapTotal /proc/meminfo
check free memory
free

Disk Space Requirements
Between 150 and 200 MB of disk space the /tmp directory
df -k /tmp (this will give in kb if you want in larger size give -h)
Maximum space requirement for enterprise installation 1.5 GB

Checking the Software Requirements
Operating system Requirements
Red Hat Enterprise Linux 5.0

Determining distribution and version of Linux
# cat /etc/issue
For installation purpose edit the following file to make the release as 4 Even though oracle 10g is certified on 5 oracle is recommending changing this to 4 to pass the os checking (oracle release notes for 10g on linux)
On Oracle Enterprise Linux 5 and Red Hat Enterprise Linux 5, the installation passes the operating system prerequisite checks if you change each 5 to 4 in the /etc/redhat-release file. Ensure that you replace the original values in the /etc/redhat-release file after the Oracle installation is complete.
Make a back up first C p /etc/redhat-release /etc/redhat-release.bck
Now edit and change version number to 4

Kernel Requirements 2.6.18
check if the required kernel is installed:
uname -r

Package Requirements

Oracle Enterprise Linux 5.0, and Red Hat Enterprise Linux 5.0 The following packages (or later versions) must be installed:
binutils-2.17.50.0.6-2.el5
compat-libstdc++-33-3.2.3-61
elfutils-libelf-0.125-3.el5
elfutils-libelf-devel-0.125
gcc-4.1.1-52 gcc-c++-4.1.1-52
glibc-2.5-12 glibc-common-2.5-12
glibc-devel-2.5-12
glibc-headers-2.5-12
libaio-0.3.106
libaio-devel-0.3.106
libgcc-4.1.1-52
libstdc++-4.1.1
libstdc++-devel-4.1.1-52.e15
make-3.81-1.1
sysstat-7.0.0
unixODBC-2.2.11
unixODBC-devel-2.2.11
libXp-1*
in the list of packages that oracle has listed ” libXp-“ is not there but when after we start installation if this package is not there the following error will be thrown
(check this package if it is not there when you run ./runInstaller you will get a “java.lang.UnsatisfiedLinkError: /tmp/OraInstall2005-08-30_10-54-49PM/jre/1.4.2/lib/i386/libawt.so: libXp.so.6: cannot open shared object file: No such file or directory”

Check if the required package is installed using following command
rpm -q package_name ex: rpm –q unixODBC

Installing package
rpm -ivh packagename
rpm –ivh package_name
ex : rpm – ivh sysstat-7.0.0

Removing package
rpm -e package_name
ex : rpm – e sysstat-7.0.0

# hostname

The output of this command should be similar to the following:
Rac1.localdomain.com(this is my hostname)
Verify that the domain name has not been set dynamically by using the domainname command as follows:

# domainname
This command should not return any results.
Verify that the hosts file contains the fully qualified host name by using the following command:

# cat /etc/hosts grep `eval hostname`
The output of this command should contain an entry for the fully qualified host name and for localhost.
For example:

192.168.1.101 rac1.localdomain.com
rac1 127.0.0.1 localhost.localdomain
localhost If the hosts file does not contain the fully qualified host name, then open the file(/etc/hosts) and make the required changes in it.
You can set up hostname using GUI go to system – administration - network

Creating the Oracle Inventory and DBA Group
groupadd oinstall
groupadd dba

Creating the Oracle Software Owner User
# useradd -g oinstall -G dba oracle
The -g option specifies the primary group, which must be the Oracle Inventory group, for example oinstall
The -G option specifies the secondary groups, which must include the OSDBA group and if required, the OSOPER group. For example, dba or dba,oper
Set the password of the oracle user:
# passwd oracle
Verifying that the User nobody Exists 1.
To determine whether the user exists, enter the following command:
# id nobody
If the nobody user does not exist, then enter the following command to create it: useradd nobody
Configuring Kernel Parameters
Using any text editor, create or edit the /etc/sysctl.conf file, and add or edit lines similar to the following: if any of the current values are larger than the recommended value, then specify the larger value.
kernel.shmall = 2097152
kernel.shmmax = 2147483648

kernel.shmmni = 4096
kernel.sem = 250 32000 100 128
fs.file-max = 65536
net.ipv4.ip_local_port_range = 1024 65000
net.core.rmem_default=262144
net.core.wmem_default=262144
net.core.rmem_max=262144
net.core.wmem_max=262144
to get the effect of new kernel setting run
/sbin/sysctl -p
Setting Shell Limits for the oracle User

Add the following lines in the /etc/security/limits.conf file:
oracle soft nproc 16384
oracle hard nproc 16384
oracle soft nofile 65536
oracle hard nofile 65536

Add or edit the following line in the /etc/pam.d/login file, if it does not already exist:
session required /lib/security/pam_limits.so

For the Bourne, Bash, or Korn shell, add the following lines to the /etc/profile file
if [ $USER = "oracle" ]; then
if [ $SHELL = "/bin/ksh" ]; then
ulimit -p 16384
ulimit -n 65536
else
ulimit -u 16384 -n 65536
fi
fi
If you are not logged in as the oracle user, then switch user to oracle:
$ su - oracle
To determine the default shell for the oracle user, enter the following command:
$ echo $SHELL
Open the oracle user's shell startup file in any text editor:
Bourne shell (sh), Bash shell (bash), or Korn shell (ksh):
$ vi .bash_profile
Enter or edit the following line, specifying a value of 022 for the default file mode creation mask:
umask 022

If the ORACLE_SID, ORACLE_HOME, or ORACLE_BASE environment variable is set in the file, then remove the corresponding lines from the file. Save the file, and exit from the editor. To run the shell startup script, enter one of the following commands:
* Bash shell on Red Hat Enterprise Linux:
$ . ./.bash_profile

To verify that the environment has been set correctly, enter the following commands: $ umask $ env more
Verify that the umask command displays a value of 22, 022, or 0022

Create directories for oracle software and datafiles
Mkdir –P /u01/app/oracle
If oracle user doesn’t not have privilege change to root and do as follwing
Su - root
mkdir P /u01/app/oracle
Change folder owner to oracle
chown –r oracle:oinstall /u01/app/oracle
set folder priviliges
chmod –r 770 /u01/app/oracle

Data files
mkdir –P /u02/oradata
chown –r oracle:oinstall /u02/oradata
Chmod –r 770 /u02/oradata
now we have to start a xterminal
as root run
xhost +
change user to oracle
su - oracle
open an x terminal by running
xterm
copy the database installation to disk
change privilege so that oracle can execute .runInstall
ex:
location you copied
/var/stage/10g
Change owner if its not under oracle
chown –r oracle:oinstall /var/stage/10g
chmod –r 770 /var/stage/10g
Now change directory to stagin area and run
. runInstall

error encountered when tried to start the listener

Linux Error: 29 Illegal Seek

http://forums.oracle.com/forums/thread.jspa?threadID=520405

Include in /etc/hosts file
127.0.0.1 localhost.localdomain localhost




Wednesday, 17 March 2010

Type english get Malayalam

http://t13n.googlecode.com/svn/trunk/blet/docs/help_ml.html

Monday, 15 March 2010

Lost Updates

Lost updates happen in multi user environment quite normally if the application is not well built. It happens when you have multiple users and some of them are trying to update same data around same time.

User’s action from query to update: - Data is retrieved to user's memory, make the necessary changes and puts the data back to the database.

Data is read from the database to the users’ machine around the same time, session one makes required changes and saves, by this time the other session also does some changes and saves. If there is no checking the second session will overwrite the first session's changes.

Let’s take an application to explain

This is an application which will be used by users for booking for programmes. The current situation is that only one seat is available but two users are querying the system for booking at the same time.

User_1 queries the system and gets the status of booking “open” only for one person

User_2 queries the system and gets the status of booking “open” only for one person

User_1 books so the status changed to “booked” (no room for new booking)

User_2 still sees the status as “open” on his screen

User_2 books and so the status changes to “booked” and gets saved

Ex:

Don’t forget to set serveroutput on !

--create table for programme booking

CREATE TABLE prg_bookings(envent_id NUMBER,no_booking integer,book_limit integer) ;

--insert a programme with id 1001

INSERT INTO prg_bookings values(1001,9,10);

commit;

CREATE OR REPLACE PROCEDURE PRINT (text VARCHAR2)

IS

BEGIN

DBMS_OUTPUT.put_line (text);

END PRINT;

Run session 1 and session 2 in two different sessions, run session 1 first and then session 2 in less than 10 seconds. In examples I have used dbms lock so that both sessions will see the same data.

Session 1

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

BEGIN

SELECT

no_booking

,book_limit

INTO

v_total_booking

,v_booking_limit

FROM prg_bookings

WHERE

envent_id = 1001 ;

--thinking of booking

print('Thinking of Booking!');

DBMS_LOCK.sleep (10);

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET no_booking= v_total_booking +1

WHERE envent_id = 1001 ;

END IF;

IF (SQL%ROWCOUNT) = 1

THEN

PRINT (SQL%ROWCOUNT || ' i have booked');

Commit;

END IF;

END;

Session 2

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

BEGIN

SELECT

no_booking

,book_limit

INTO

v_total_booking

,v_booking_limit

FROM prg_bookings

WHERE

envent_id = 1001 ;

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET no_booking= v_total_booking +1

WHERE envent_id = 1001 ;

END IF;

IF (SQL%ROWCOUNT) = 1

THEN

PRINT (SQL%ROWCOUNT || ' i have booked');

Commit;

END IF;

END;

Here the booking done by session 1 will be lost. This issue is tracked in two ways

  1. Pessimistic Locking

Pessimistic locking is the mechanism where at the time of user’s intention to update any row, lock that particular row with select ....for update.

ex:

SELECT

no_booking

,book_limit

FROM prg_bookings

WHERE

envent_id = 1001

FOR UPDATE;

  1. Optimistic Locking :- is done in the following ways

Column compare

Hash compare

Timestamp compare

Version compare

Ora_rowscn(new in 10g)

Use this update statement to reset no of booking column
UPDATE prg_bookings SET no_booking = 9 WHERE envent_id = 1001;
commit;



Column compare

Session 1

--session 1

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

BEGIN

SELECT

no_booking

,book_limit

INTO

v_total_booking

,v_booking_limit

FROM prg_bookings

WHERE

envent_id = 1001 ;

--thinking of booking

print('Thinking of Booking!');

DBMS_LOCK.sleep (10);

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET no_booking= v_total_booking +1

WHERE envent_id = 1001 and no_booking = v_total_booking ;

END IF;

IF (SQL%ROWCOUNT) = 0

THEN

PRINT ('Id is already booked by someone else');

ELSE

PRINT (SQL%ROWCOUNT || 'i have booked');

END IF;
END;

Session 2

--session 2

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

BEGIN

SELECT

no_booking

,book_limit

INTO

v_total_booking

,v_booking_limit

FROM prg_bookings

WHERE

envent_id = 1001 ;

--determined to book

print('determined to book!');

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET no_booking= v_total_booking +1

WHERE envent_id = 1001 and no_booking = v_total_booking ;

END IF;

IF (SQL%ROWCOUNT) = 0

THEN

PRINT ('Id is already bookedby someone else');

ELSE

PRINT (SQL%ROWCOUNT || 'i have booked');

commit;

END IF;

END;

Hash compare (this technique is used by oracle apex)

Timestamp compare

--let's add a column for time stamp comaparison

ALTER TABLE prg_bookings

ADD tim TIMESTAMP;

UPDATE prg_bookings SET no_booking = 9,tim=localtimestamp

WHERE envent_id = 1001;

commit;

session 1
--session 1

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

v_tim_at_qry TIMESTAMP;

BEGIN

SELECT

no_booking

,book_limit

,tim

INTO

v_total_booking

,v_booking_limit

,v_tim_at_qry

FROM prg_bookings

WHERE

envent_id = 1001 ;

--thinking of booking

print('Thinking of Booking!');

DBMS_LOCK.sleep (10);

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET

no_booking= v_total_booking + 1

,tim = localtimestamp

WHERE envent_id = 1001 and tim = v_tim_at_qry ;

END IF;

IF (SQL%ROWCOUNT) = 0

THEN

PRINT ('Id is already booked by someone else. Timestamp has been changed,tim stamp at query was ' || v_tim_at_qry );

ELSE

PRINT (SQL%ROWCOUNT || 'i have booked');

END IF;

END;

session 2

--session 2

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

v_tim_at_qry TIMESTAMP;

BEGIN

SELECT

no_booking

,book_limit

,tim

INTO

v_total_booking

,v_booking_limit

,v_tim_at_qry

FROM prg_bookings

WHERE

envent_id = 1001 ;

--determined to book

print('determined to book!');

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET

no_booking= v_total_booking + 1

,tim = localtimestamp

WHERE envent_id = 1001 and tim = v_tim_at_qry ;

END IF;

IF (SQL%ROWCOUNT) = 0

THEN

PRINT ('Id is already bookedby someone else');

ELSE

PRINT (SQL%ROWCOUNT || 'i have booked');

commit;

END IF;

END;

Version compare
-let us add another column for version compare

ALTER TABLE prg_bookings DROP COLUMN tim;

ALTER TABLE prg_bookings

ADD ver INTEGER;

UPDATE prg_bookings SET no_booking = 9,ver=0 WHERE envent_id = 1001 ;

commit;

session 1

--session 1

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

v_ver PLS_INTEGER;

BEGIN

SELECT

no_booking

,book_limit

,ver

INTO

v_total_booking

,v_booking_limit

,v_ver

FROM prg_bookings

WHERE

envent_id = 1001 ;

--thinking of booking

print('Thinking of Booking!');

DBMS_LOCK.sleep (10);

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET

no_booking= v_total_booking + 1

,ver = ver+1

WHERE envent_id = 1001 and ver = v_ver ;

END IF;

IF (SQL%ROWCOUNT) = 0

THEN

PRINT ('Id is already booked by someone else. version changed,version no at query was ' || v_ver );

ELSE

PRINT (SQL%ROWCOUNT || 'i have booked');

END IF;

END;

Session 2

--session 2

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

v_ver PLS_INTEGER;

BEGIN

SELECT

no_booking

,book_limit

,ver

INTO

v_total_booking

,v_booking_limit

,v_ver

FROM prg_bookings

WHERE

envent_id = 1001 ;

--determined to book

print('determined to book!');

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET

no_booking= v_total_booking + 1

,ver = ver+1

WHERE envent_id = 1001 and ver = v_ver ;

END IF;

IF (SQL%ROWCOUNT) = 0

THEN

PRINT ('Id is already bookedby someone else');

ELSE

PRINT (SQL%ROWCOUNT || 'i have booked');

commit;

END IF;

END;

Ora_rowscn(new in 10g)

--now lets recreate the table to enable row level scn

drop table prg_bookings;

CREATE TABLE prg_bookings(envent_id NUMBER,no_booking integer,book_limit integer) rowdependencies;

INSERT INTO prg_bookings values(1001,9,10);

commit;

Session 1

--session 1

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

v_scn_at_query NUMBER;

BEGIN

SELECT

no_booking

,book_limit

,ORA_ROWSCN

INTO

v_total_booking

,v_booking_limit

,v_scn_at_query

FROM prg_bookings

WHERE

envent_id = 1001 ;

--thinking of booking

print('Thinking of Booking!');

DBMS_LOCK.sleep (10);

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET

no_booking= v_total_booking + 1

WHERE envent_id = 1001 and ORA_ROWSCN= v_scn_at_query ;

END IF;

IF (SQL%ROWCOUNT) = 0

THEN

PRINT ('Id is already booked by someone else. Scn changed, Sct at query was ' || v_scn_at_query );

ELSE

PRINT (SQL%ROWCOUNT || 'i have booked');

END IF;

END;
Session 2

--session 2

DECLARE

v_total_booking PLS_INTEGER;

v_booking_limit PLS_INTEGER;

v_scn_at_query NUMBER;

BEGIN

SELECT

no_booking

,book_limit

,ORA_ROWSCN

INTO

v_total_booking

,v_booking_limit

,v_scn_at_query

FROM prg_bookings

WHERE

envent_id = 1001 ;

--determined to book

print('determined to book!');

IF v_total_booking + 1 <= v_booking_limit THEN

UPDATE prg_bookings

SET

no_booking= v_total_booking + 1

WHERE envent_id = 1001 and ORA_ROWSCN= v_scn_at_query;

END IF;

IF (SQL%ROWCOUNT) = 0

THEN

PRINT ('Id is already booked by someone else');

ELSE

PRINT (SQL%ROWCOUNT || 'i have booked');

commit;

END IF;

END;