Tip

Keep track of who logs on and how many times per month

Do you want to track statistics on the number of times your Oracle database is logged on to, or do you get queries about when is the last time some particular account accessed the database? This trigger will update the database keeping statistics on who logs on to the database and how many times per month. I have it installed and have it running successfully on Oracle 8.1.7.0.0 and Oracle 9.2.0.

One note I would like to add is that I removed the schema name from the table name in the trigger script. To make it work smoothly, anyone wanting to use this procedure should create a public synonym for the table as follows:

create public synonym user_logins for .user_logins;
Other than that I can see no reason why anyone can't use it.

First, create a table to hold the stats:

create table user_logins (
userid        varchar(30),
logon_month   number,
logon_cnt     number
);
Then create or replace trigger catch_logins after logon on database:
declare
curr_month   number(6);
cnt_month    number(8);
begin
select to_char(sysdate,'YYYYMM') into curr_month from dual;
select count(*) into cnt_month from user_logins
where userid = user and logon_month = curr_month;
if cnt_month = 0
then
insert into user_logins 
values (user, curr_month, 1);
else
update user_logins
set logon_cnt = logon_cnt + 1
where userid = user and logon_month = curr_month;
end if;
end;
/

For More Information

    Requires Free Membership to View

  • Feedback:
    E-mail the editor with your thoughts about this tip.
  • More tips: Hundreds of free Oracle tips and scripts.
  • Tip contest: Have an Oracle tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize -- submit your tip today!
  • Ask the Experts: Our SQL, database design, Oracle, SQL Server, DB2, metadata, and data warehousing gurus are waiting to answer your toughest questions.
  • Forums: Ask your technical Oracle questions--or help out your peers by answering them--in our active forums.
  • Best Web Links: Oracle tips, tutorials, and scripts from around the Web.

This was first published in October 2002

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to:

Disclaimer: Our Tips Exchange is a forum for you to share technical advice and expertise with your peers and to learn from other enterprise IT professionals. TechTarget provides the infrastructure to facilitate this sharing of information. However, we cannot guarantee the accuracy or validity of the material submitted. You agree that your use of the Ask The Expert services and your reliance on any questions, answers, information or other materials received through this Web site is at your own risk.