Share this
Controlling Oracle Fetch Sizes with Oraaccess.xml
by Jared Still on May 21, 2025 8:59:42 AM
Most Oracle DBAs are probably familiar with the concept of fetch size. The fetch size is the number of rows that are fetched from the database in a single round trip.
This can have a significant impact on performance, especially when dealing with large result sets.
In sqlplus, the default fetch size is 15 rows. This can be changed using the set array size command.
In Perl, the fetch size can be controlled by setting the database handle attribute RowCacheSize: $dbh->{RowCacheSize} = 100
In JDBC, the default fetch size is 10 rows. This can be changed using the setFetchSize method on the Statement or PreparedStatement object.
In Python the fetch can be changed using the fetch_size attribute of the PreparedStatement object, or at a session level with the default_fetch_size attribute of the connection object.
This is all good to know. However, this does not really help the DBA or Performance Analyst that would like to improve the network performance of an application.
We don't usually have access to the source code, and even if we did, we would probably not be allowed to change it.
Oracle has a file that allows an easy way to change the fetch size of any applications that use Oracle libraries for connections.
This file is called oraaccess.xml and is by default located in the $ORACLE_HOME/network/admin directory.
This method works with applications using any of the following:
- Perl DBD::Oracle
- Python cx_Oracle
- Java Thick Client
- Any application that is compiled with Oracle libraries.
- C, C++
- Fortran
- COBOL
This method will not work for applications that do not use Oracle libraries for connections.
The Java Thin Client is a good example of this.
The Java Thin Client does not use the Oracle libraries for connections, and therefore does not use the oraaccess.xml file.
There are other methods that may be used to control the fetch size of applications that do not use Oracle libraries for connections, but we will not cover them here.
A well-known Oracle application that can make use of oraaccess.xml is SQL*Plus.
What is oraaccess.xml?
The oraaccess.xml file is an XML file that contains configuration settings for Oracle client applications.
It allows you to specify various parameters, including the fetch size, for all Oracle client applications that use the Oracle libraries.
For our purposes, the oraaccess.xml file will be used only to set the default fetch size for tests with sqlplus.
How to set the fetch size in oraaccess.xml
It is fairly straightforward to set the fetch size in oraaccess.xml as per the following example:
<?xml version="1.0" encoding="ASCII" ?>
<oraaccess xmlns="http://xmlns.oracle.com/oci/oraaccess"
xmlns:oci="http://xmlns.oracle.com/oci/oraaccess"
schemaLocation="http://xmlns.oracle.com/oci/oraaccess
http://xmlns.oracle.com/oci/oraaccess.xsd">
<default_parameters>
<prefetch>
<rows>100</rows>
</prefetch>
</default_parameters>
</oraaccess>
The 'prefetch' element is used to set the fetch size. The 'rows' element specifies the number of rows to fetch in a single round trip.
That's all there is to it.
Testing with SQL*Plus and mrskew
You are likely familiar with sqlplus, as it is a standard oracle tool.
Method R mrskew is a tool that can be used to test the database performance while running sqlplus (or any oracle database application) with different fetch sizes.
The entire suite of Method R tools are my go-to choice for analyzing Oracle SQL Trace files.
They can be found at Method R Workbench
BTW, these tools are free, and are available for Windows, Linux, and MacOS.
All code used in this article is available at oraaccess-xml, and so will not be included in the article.
Any rc files used with mrskew are available here: jkstill mrtools rc files
How to test
The default location for *.ora oracle configuration files is $ORACLE_HOME/network/admin. This is also where oraaccess.xml is located.
This location can be changed by setting the TNS_ADMIN environment variable to point to a different directory.
Here is how the testing will proceed:
- create and populate a test table
- the script will create a table with 100k rows, only if it does not already exist
- sqlplus will be run with sqltrace enabled
- the trace file will be fetched and analyzed with mrskew
- Use TNS_ADMIN to point to the directory where oraaccess.xml is located
- NONE: default location. In this case there is no oraaccess.xml file at OH/network/admin
- 100/oraaccess.xml: 100 row fetch size
- 500/oraaccess.xml: 500 row fetch size
- 1000/oraaccess.xml: 1000 row fetch size
Here is a sample run of the script:
$ ./compare-oraaccess-xml.sh
Creating Table arraytest
PL/SQL procedure successfully completed.
Creating rows in arraytest
PL/SQL procedure successfully completed.
TNS_ADMIN:
TNS_ADMIN: /home/jkstill/oracle/oraaccess-xml/100
TNS_ADMIN: /home/jkstill/oracle/oraaccess-xml/500
TNS_ADMIN: /home/jkstill/oracle/oraaccess-xml/1000
$
Here are the contents of the trace/ directory:
$ ls -latr trace/*.trc
-rw-r----- 1 jkstill jkstill 2358427 May 1 11:11 trace/orcl1901_ora_1358976_ARRAY-NONE.trc
-rw-r----- 1 jkstill jkstill 343126 May 1 11:11 trace/orcl1901_ora_1359072_ARRAY-100.trc
-rw-r----- 1 jkstill jkstill 74920 May 1 11:11 trace/orcl1901_ora_1359116_ARRAY-500.trc
-rw-r----- 1 jkstill jkstill 53364 May 1 11:11 trace/orcl1901_ora_1359158_ARRAY-1000.trc
Just comparing the sizes of the trace files gives us a good idea of the performance of the different fetch sizes.
Analyze the trace files with mrskew
The rc file fetch-snmfc.rc is used to analyze the trace files. This rc file will restrict the output to FETCH, EXEC calls that had the FETCH included, and SQL*Net messages to and from the client.
In each case, the FETCH and EXEC calls are grouped by name and the number of rows returned per call.
The SQL*Net messages are grouped by name only.
Default Fetch Size
The baseline is to not use any oraaccess.xml file. This means the default fetch size of 15 rows for sqlplus will be used.
We see that 6,666 FETCH calls were made that each returned 15 rows.
The total number of rows returned was 100,000.
Of particular interest is the time spent waiting on the network.
This is not because the network was slow (average wait time was 0.000397 seconds), but because the application made far too many calls to the database.
$ mrskew --rc fetch-snmfc.rc trace/orcl1901_ora_1358976_ARRAY-NONE.trc
CALL:NNNNNNNNN DURATION % CALLS MEAN MIN MAX
---------------------------------------- -------- ------ ------ -------- -------- --------
SQL*Net message from client: 2.646101 99.9% 6,671 0.000397 0.000187 0.001386
FETCH:000000015 0.001155 0.0% 6,666 0.000000 0.000000 0.000016
SQL*Net message to client: 0.000361 0.0% 6,671 0.000000 0.000000 0.000002
FETCH:000000001 0.000018 0.0% 1 0.000018 0.000018 0.000018
EXEC:000000000 0.000010 0.0% 1 0.000010 0.000010 0.000010
FETCH:000000009 0.000000 0.0% 1 0.000000 0.000000 0.000000
---------------------------------------- -------- ------ ------ -------- -------- --------
TOTAL (6) 2.647645 100.0% 20,011 0.000132 0.000000 0.001386
100 Row Fetch Size
With 100 rows, the total amount of time spent waiting on the network is reduced from 2.646 seconds to 1.671 seconds.
$ mrskew --rc fetch-snmfc.rc trace/orcl1901_ora_1359072_ARRAY-100.trc
CALL:NNNNNNNNN DURATION % CALLS MEAN MIN MAX
---------------------------------------- -------- ------ ----- -------- -------- --------
SQL*Net message from client: 1.662761 99.5% 956 0.001739 0.000231 0.002668
FETCH:000000105 0.008220 0.5% 951 0.000009 0.000000 0.000035
SQL*Net message to client: 0.000051 0.0% 956 0.000000 0.000000 0.000001
FETCH:000000100 0.000023 0.0% 1 0.000023 0.000023 0.000023
EXEC:000000000 0.000009 0.0% 1 0.000009 0.000009 0.000009
FETCH:000000045 0.000007 0.0% 1 0.000007 0.000007 0.000007
---------------------------------------- -------- ------ ----- -------- -------- --------
TOTAL (6) 1.671071 100.0% 2,866 0.000583 0.000000 0.002668
500 Row Fetch Size
With a fetch size of 500 rows, the total amount of time spent waiting on the network is reduced from 1.671 seconds to 1.530 seconds.
This is not nearly as large a gain as was seen when comparing the default fetch size of 15 rows to 100 rows.
When large amounts of data must be moved however, the difference could still be significant.
$ mrskew --rc fetch-snmfc.rc trace/orcl1901_ora_1359116_ARRAY-500.trc
CALL:NNNNNNNNN DURATION % CALLS MEAN MIN MAX
---------------------------------------- -------- ------ ----- -------- -------- --------
SQL*Net message from client: 1.524779 99.6% 200 0.007624 0.000221 0.008691
FETCH:000000510 0.006030 0.4% 195 0.000031 0.000000 0.000054
FETCH:000000500 0.000045 0.0% 1 0.000045 0.000045 0.000045
SQL*Net message to client: 0.000035 0.0% 200 0.000000 0.000000 0.000001
FETCH:000000050 0.000011 0.0% 1 0.000011 0.000011 0.000011
EXEC:000000000 0.000010 0.0% 1 0.000010 0.000010 0.000010
---------------------------------------- -------- ------ ----- -------- -------- --------
TOTAL (6) 1.530910 100.0% 598 0.002560 0.000000 0.008691
1000 Row Fetch Size
The final test was to set the fetch size to 1000 rows.
Again, the time spent waiting on the network is reduced from 1.530 seconds to 1.492 seconds.
A difference of 0.038 seconds may not be important most of the time.
This test is for a relatively small amount of data (100k rows).
If this test were for 500 million rows, the difference would be 190 seconds.
This may be important for large volumes of data.
$ mrskew --rc fetch-snmfc.rc trace/orcl1901_ora_1359158_ARRAY-1000.trc
CALL:NNNNNNNNN DURATION % CALLS MEAN MIN MAX
---------------------------------------- -------- ------ ----- -------- -------- --------
SQL*Net message from client: 1.485908 99.6% 103 0.014426 0.000205 0.015652
FETCH:000001005 0.006022 0.4% 98 0.000061 0.000000 0.000138
FETCH:000001000 0.000083 0.0% 1 0.000083 0.000083 0.000083
FETCH:000000510 0.000035 0.0% 1 0.000035 0.000035 0.000035
SQL*Net message to client: 0.000017 0.0% 103 0.000000 0.000000 0.000002
EXEC:000000000 0.000011 0.0% 1 0.000011 0.000011 0.000011
---------------------------------------- -------- ------ ----- -------- -------- --------
TOTAL (6) 1.492076 100.0% 307 0.004860 0.000000 0.015652
Conclusion
The oraaccess.xml file is a powerful tool that can be used to control the fetch size of Oracle client applications.
It is simple to use and can have a significant impact on performance, especially when dealing with large result sets.
Share this
- Technical Track (967)
- Oracle (412)
- MySQL (140)
- Cloud (128)
- Microsoft SQL Server (117)
- Open Source (90)
- Google Cloud (81)
- Microsoft Azure (63)
- Amazon Web Services (AWS) (58)
- Big Data (52)
- Google Cloud Platform (46)
- Cassandra (44)
- DevOps (41)
- Pythian (33)
- Linux (30)
- Database (26)
- Performance (25)
- Podcasts (25)
- Site Reliability Engineering (25)
- PostgreSQL (24)
- Oracle E-Business Suite (23)
- Oracle Database (22)
- Docker (21)
- DBA (20)
- Security (20)
- Exadata (18)
- MongoDB (18)
- Oracle Cloud Infrastructure (OCI) (18)
- Oracle Exadata (18)
- Automation (17)
- Hadoop (16)
- Oracleebs (16)
- Amazon RDS (15)
- Ansible (15)
- Snowflake (15)
- ASM (13)
- Artificial Intelligence (AI) (13)
- BigQuery (13)
- Replication (13)
- Advanced Analytics (12)
- Data (12)
- GenAI (12)
- Kubernetes (12)
- LLM (12)
- Authentication, SSO and MFA (11)
- Cloud Migration (11)
- Machine Learning (11)
- Rman (11)
- Datascape Podcast (10)
- Monitoring (10)
- Oracle Applications (10)
- Apache Cassandra (9)
- ChatGPT (9)
- Data Guard (9)
- Infrastructure (9)
- Python (9)
- Series (9)
- AWR (8)
- High Availability (8)
- Oracle EBS (8)
- Oracle Enterprise Manager (OEM) (8)
- Percona (8)
- Apache Beam (7)
- Data Governance (7)
- Innodb (7)
- Microsoft Azure SQL Database (7)
- Migration (7)
- Myrocks (7)
- Performance Tuning (7)
- Data Enablement (6)
- Data Visualization (6)
- Database Performance (6)
- Oracle Enterprise Manager (6)
- Orchestrator (6)
- RocksDB (6)
- Serverless (6)
- Azure Data Factory (5)
- Azure Synapse Analytics (5)
- Covid-19 (5)
- Disaster Recovery (5)
- Generative AI (5)
- Google BigQuery (5)
- Mariadb (5)
- Microsoft (5)
- Scala (5)
- Windows (5)
- Xtrabackup (5)
- Airflow (4)
- Analytics (4)
- Apex (4)
- Cloud Security (4)
- Cloud Spanner (4)
- CockroachDB (4)
- Data Management (4)
- Data Pipeline (4)
- Data Security (4)
- Data Strategy (4)
- Database Administrator (4)
- Database Management (4)
- Database Migration (4)
- Dataflow (4)
- Fusion Middleware (4)
- Google (4)
- Oracle Autonomous Database (Adb) (4)
- Oracle Cloud (4)
- Prometheus (4)
- Redhat (4)
- Slob (4)
- Ssl (4)
- Terraform (4)
- Amazon Relational Database Service (Rds) (3)
- Apache Kafka (3)
- Apexexport (3)
- Aurora (3)
- Business Intelligence (3)
- Cloud Armor (3)
- Cloud Database (3)
- Cloud FinOps (3)
- Cosmos Db (3)
- Data Analytics (3)
- Data Integration (3)
- Database Monitoring (3)
- Database Troubleshooting (3)
- Database Upgrade (3)
- Databases (3)
- Dataops (3)
- Digital Transformation (3)
- ERP (3)
- Google Chrome (3)
- Google Cloud Sql (3)
- Google Workspace (3)
- Graphite (3)
- Heterogeneous Database Migration (3)
- Liquibase (3)
- Oracle Data Guard (3)
- Oracle Live Sql (3)
- Oracle Rac (3)
- Perl (3)
- Rdbms (3)
- Remote Teams (3)
- S3 (3)
- SAP (3)
- Tensorflow (3)
- Adf (2)
- Adop (2)
- Amazon Data Migration Service (2)
- Amazon Ec2 (2)
- Amazon S3 (2)
- Apache Flink (2)
- Ashdump (2)
- Atp (2)
- Autonomous (2)
- Awr Data Mining (2)
- Cloud Cost Optimization (2)
- Cloud Data Fusion (2)
- Cloud Hosting (2)
- Cloud Infrastructure (2)
- Cloud Shell (2)
- Cloud Sql (2)
- Conferences (2)
- Cosmosdb (2)
- Cost Management (2)
- Cyber Security (2)
- Data Analysis (2)
- Data Discovery (2)
- Data Engineering (2)
- Data Migration (2)
- Data Modeling (2)
- Data Quality (2)
- Data Streaming (2)
- Data Warehouse (2)
- Database Consulting (2)
- Database Migrations (2)
- Dataguard (2)
- Docker-Composer (2)
- Enterprise Data Platform (EDP) (2)
- Etl (2)
- Events (2)
- Gemini (2)
- Health Check (2)
- Infrastructure As Code (2)
- Innodb Cluster (2)
- Innodb File Structure (2)
- Innodb Group Replication (2)
- NLP (2)
- Neo4J (2)
- Nosql (2)
- Open Source Database (2)
- Oracle Datase (2)
- Oracle Extended Manager (Oem) (2)
- Oracle Flashback (2)
- Oracle Forms (2)
- Oracle Installation (2)
- Oracle Io Testing (2)
- Podcast (2)
- Power Bi (2)
- Redshift (2)
- Remote DBA (2)
- Remote Sre (2)
- SAP HANA Cloud (2)
- Single Sign-On (2)
- Webinars (2)
- X5 (2)
- Actifio (1)
- Adf Custom Email (1)
- Adrci (1)
- Advanced Data Services (1)
- Afd (1)
- Ahf (1)
- Alloydb (1)
- Amazon (1)
- Amazon Athena (1)
- Amazon Aurora Backtrack (1)
- Amazon Efs (1)
- Amazon Redshift (1)
- Amazon Sagemaker (1)
- Amazon Vpc Flow Logs (1)
- Analysis (1)
- Analytical Models (1)
- Anisble (1)
- Anthos (1)
- Apache (1)
- Apache Nifi (1)
- Apache Spark (1)
- Application Migration (1)
- Ash (1)
- Asmlib (1)
- Atlas CLI (1)
- Awr Mining (1)
- Aws Lake Formation (1)
- Azure Data Lake (1)
- Azure Data Lake Analytics (1)
- Azure Data Lake Store (1)
- Azure Data Migration Service (1)
- Azure OpenAI (1)
- Azure Sql Data Warehouse (1)
- Batches In Cassandra (1)
- Business Insights (1)
- Chown (1)
- Chrome Security (1)
- Cloud Browser (1)
- Cloud Build (1)
- Cloud Consulting (1)
- Cloud Data Warehouse (1)
- Cloud Database Management (1)
- Cloud Dataproc (1)
- Cloud Foundry (1)
- Cloud Manager (1)
- Cloud Networking (1)
- Cloud SQL Replica (1)
- Cloud Scheduler (1)
- Cloud Services (1)
- Cloud Strategies (1)
- Compliance (1)
- Conversational AI (1)
- DAX (1)
- Data Analytics Platform (1)
- Data Box (1)
- Data Classification (1)
- Data Cleansing (1)
- Data Encryption (1)
- Data Estate (1)
- Data Flow Management (1)
- Data Insights (1)
- Data Integrity (1)
- Data Lake (1)
- Data Leader (1)
- Data Lifecycle Management (1)
- Data Lineage (1)
- Data Masking (1)
- Data Mesh (1)
- Data Migration Assistant (1)
- Data Migration Service (1)
- Data Mining (1)
- Data Monetization (1)
- Data Policy (1)
- Data Profiling (1)
- Data Protection (1)
- Data Retention (1)
- Data Safe (1)
- Data Sheets (1)
- Data Summit (1)
- Data Vault (1)
- Data Warehouse Modernization (1)
- Database Auditing (1)
- Database Consultant (1)
- Database Link (1)
- Database Modernization (1)
- Database Provisioning (1)
- Database Provisioning Failed (1)
- Database Replication (1)
- Database Scaling (1)
- Database Schemas (1)
- Database Security (1)
- Databricks (1)
- Datascape 59 (1)
- DeepSeek (1)
- Duet AI (1)
- Edp (1)
- Gcp Compute (1)
- Gcp-Spanner (1)
- Global Analytics (1)
- Google Analytics (1)
- Google Cloud Architecture Framework (1)
- Google Cloud Data Services (1)
- Google Cloud Partner (1)
- Google Cloud Spanner (1)
- Google Cloud VMware Engine (1)
- Google Compute Engine (1)
- Google Dataflow (1)
- Google Datalab (1)
- Google Grab And Go (1)
- Graph Algorithms (1)
- Graph Databases (1)
- Graph Inferences (1)
- Graph Theory (1)
- GraphQL (1)
- Healthcheck (1)
- Information (1)
- Infrastructure As A Code (1)
- Innobackupex (1)
- Innodb Concurrency (1)
- Innodb Flush Method (1)
- It Industry (1)
- Kubeflow (1)
- LMSYS Chatbot Arena (1)
- Linux Host Monitoring (1)
- Linux Storage Appliance (1)
- Looker (1)
- MMLU (1)
- Managed Services (1)
- Migrate (1)
- Migrating Ssis Catalog (1)
- Migration Checklist (1)
- MongoDB Atlas (1)
- MongoDB Compass (1)
- Newsroom (1)
- Nifi (1)
- OPEX (1)
- ORAPKI (1)
- Odbcs (1)
- Odbs (1)
- On-Premises (1)
- Ora-01852 (1)
- Ora-7445 (1)
- Oracle Cursor (1)
- Oracle Database Appliance (1)
- Oracle Database Se2 (1)
- Oracle Database Standard Edition 2 (1)
- Oracle Database Upgrade (1)
- Oracle Database@Google Cloud (1)
- Oracle Exadata Smart Scan (1)
- Oracle Licensing (1)
- Oracle Linux Virtualization Manager (1)
- Oracle Oda (1)
- Oracle Openworld (1)
- Oracle Parallelism (1)
- Oracle RMAN (1)
- Oracle Rdbms (1)
- Oracle Real Application Clusters (1)
- Oracle Reports (1)
- Oracle Security (1)
- Oracle Wallet (1)
- Perfomrance (1)
- Performance Schema (1)
- Policy (1)
- Prompt Engineering (1)
- Public Cloud (1)
- Pythian News (1)
- Rdb (1)
- Replication Compatibility (1)
- Replication Error (1)
- Retail (1)
- Scaling Ir (1)
- Securing Sql Server (1)
- Security Compliance (1)
- Serverless Computing (1)
- Sso (1)
- Tenserflow (1)
- Teradata (1)
- Vertex AI (1)
- Vertica (1)
- Videos (1)
- Workspace Security (1)
- Xbstream (1)
- May 2025 (3)
- March 2025 (2)
- February 2025 (1)
- January 2025 (2)
- December 2024 (1)
- October 2024 (2)
- September 2024 (7)
- August 2024 (4)
- July 2024 (2)
- June 2024 (6)
- May 2024 (3)
- April 2024 (2)
- February 2024 (1)
- January 2024 (11)
- December 2023 (10)
- November 2023 (11)
- October 2023 (10)
- September 2023 (8)
- August 2023 (6)
- July 2023 (2)
- June 2023 (13)
- May 2023 (4)
- April 2023 (6)
- March 2023 (10)
- February 2023 (6)
- January 2023 (5)
- December 2022 (10)
- November 2022 (10)
- October 2022 (10)
- September 2022 (13)
- August 2022 (16)
- July 2022 (12)
- June 2022 (13)
- May 2022 (11)
- April 2022 (4)
- March 2022 (5)
- February 2022 (4)
- January 2022 (14)
- December 2021 (16)
- November 2021 (11)
- October 2021 (6)
- September 2021 (11)
- August 2021 (6)
- July 2021 (9)
- June 2021 (4)
- May 2021 (8)
- April 2021 (16)
- March 2021 (16)
- February 2021 (6)
- January 2021 (12)
- December 2020 (12)
- November 2020 (17)
- October 2020 (11)
- September 2020 (10)
- August 2020 (11)
- July 2020 (13)
- June 2020 (6)
- May 2020 (9)
- April 2020 (18)
- March 2020 (21)
- February 2020 (13)
- January 2020 (15)
- December 2019 (10)
- November 2019 (11)
- October 2019 (12)
- September 2019 (16)
- August 2019 (15)
- July 2019 (10)
- June 2019 (16)
- May 2019 (20)
- April 2019 (21)
- March 2019 (14)
- February 2019 (18)
- January 2019 (18)
- December 2018 (5)
- November 2018 (16)
- October 2018 (12)
- September 2018 (20)
- August 2018 (27)
- July 2018 (31)
- June 2018 (34)
- May 2018 (28)
- April 2018 (27)
- March 2018 (17)
- February 2018 (8)
- January 2018 (20)
- December 2017 (14)
- November 2017 (4)
- October 2017 (1)
- September 2017 (3)
- August 2017 (5)
- July 2017 (4)
- June 2017 (2)
- May 2017 (7)
- April 2017 (7)
- March 2017 (8)
- February 2017 (8)
- January 2017 (5)
- December 2016 (3)
- November 2016 (4)
- October 2016 (8)
- September 2016 (9)
- August 2016 (10)
- July 2016 (9)
- June 2016 (8)
- May 2016 (13)
- April 2016 (16)
- March 2016 (13)
- February 2016 (11)
- January 2016 (6)
- December 2015 (11)
- November 2015 (11)
- October 2015 (5)
- September 2015 (16)
- August 2015 (4)
- July 2015 (1)
- June 2015 (3)
- May 2015 (6)
- April 2015 (5)
- March 2015 (5)
- February 2015 (4)
- January 2015 (3)
- December 2014 (7)
- October 2014 (4)
- September 2014 (6)
- August 2014 (6)
- July 2014 (16)
- June 2014 (7)
- May 2014 (6)
- April 2014 (5)
- March 2014 (4)
- February 2014 (10)
- January 2014 (6)
- December 2013 (8)
- November 2013 (12)
- October 2013 (9)
- September 2013 (6)
- August 2013 (7)
- July 2013 (9)
- June 2013 (7)
- May 2013 (7)
- April 2013 (4)
- March 2013 (7)
- February 2013 (4)
- January 2013 (4)
- December 2012 (6)
- November 2012 (8)
- October 2012 (9)
- September 2012 (3)
- August 2012 (5)
- July 2012 (5)
- June 2012 (7)
- May 2012 (11)
- April 2012 (1)
- March 2012 (8)
- February 2012 (1)
- January 2012 (6)
- December 2011 (8)
- November 2011 (5)
- October 2011 (9)
- September 2011 (6)
- August 2011 (4)
- July 2011 (1)
- June 2011 (1)
- May 2011 (5)
- April 2011 (2)
- February 2011 (2)
- January 2011 (2)
- December 2010 (1)
- November 2010 (7)
- October 2010 (3)
- September 2010 (8)
- August 2010 (2)
- July 2010 (4)
- June 2010 (7)
- May 2010 (2)
- April 2010 (1)
- March 2010 (3)
- February 2010 (3)
- January 2010 (2)
- November 2009 (6)
- October 2009 (6)
- August 2009 (3)
- July 2009 (3)
- June 2009 (3)
- May 2009 (2)
- April 2009 (8)
- March 2009 (6)
- February 2009 (4)
- January 2009 (3)
- November 2008 (3)
- October 2008 (7)
- September 2008 (6)
- August 2008 (9)
- July 2008 (9)
- June 2008 (9)
- May 2008 (9)
- April 2008 (8)
- March 2008 (4)
- February 2008 (3)
- January 2008 (3)
- December 2007 (2)
- November 2007 (7)
- October 2007 (1)
- August 2007 (4)
- July 2007 (3)
- June 2007 (8)
- May 2007 (4)
- April 2007 (2)
- March 2007 (2)
- February 2007 (5)
- January 2007 (8)
- December 2006 (1)
- November 2006 (3)
- October 2006 (4)
- September 2006 (3)
- July 2006 (1)
- May 2006 (2)
- April 2006 (1)
- July 2005 (1)
No Comments Yet
Let us know what you think