Share this
Performance problems with Dynamic Statistics in Oracle 12c
by Vyacheslav Rasskazov on Jan 6, 2015 12:00:00 AM
I’ve been making some tests recently with the new Oracle 12.1.0.2 In-Memory option and have been faced with an unexpected performance problem. Here is a test case:
create table tst_1 as with q as (select 1 from dual connect by level <= 100000) select rownum id, 12345 val, mod(rownum,1000) ref_id from q,q where rownum <= 200000000; Table created. create table tst_2 as select rownum ref_id, lpad(rownum,10, 'a') name, rownum || 'a' name2</pre> from dual connect by level <= 1000; Table created. begin dbms_stats.gather_table_stats( ownname => user, tabname =>'TST_1', method_opt => 'for all columns size 1', degree => 8 ); dbms_stats.gather_table_stats( ownname => user, tabname =>'TST_2', method_opt => 'for all columns size 1' ); end; / PL/SQL procedure successfully completed. alter table tst_1 inmemory; Table altered. select count(*) from tst_1; COUNT(*) ---------- 200000000
Waiting for in-memory segment population:
select segment_name, bytes, inmemory_size from v$im_segments; SEGMENT_NAME BYTES INMEMORY_SIZE --------------- ---------- ------------- TST_1 4629463040 3533963264
Now let’s make a simple two table join:
select name, sum(val) from tst_1 a, tst_2 b where a.ref_id = b.ref_id and name2='50a' group by name; Elapsed: 00:00:00.17
Query runs pretty fast. Execution plan has the brand new vector transformation
Execution Plan
----------------------------------------------------------
Plan hash value: 213128033
--------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 54 | 7756 (21)| 00:00:01 |
| 1 | TEMP TABLE TRANSFORMATION | | | | | |
| 2 | LOAD AS SELECT | SYS_TEMP_0FD9D66FA_57B2B | | | | |
| 3 | VECTOR GROUP BY | | 1 | 24 | 5 (20)| 00:00:01 |
| 4 | KEY VECTOR CREATE BUFFERED | :KV0000 | 1 | 24 | 5 (20)| 00:00:01 |
|* 5 | TABLE ACCESS FULL | TST_2 | 1 | 20 | 4 (0)| 00:00:01 |
| 6 | HASH GROUP BY | | 1 | 54 | 7751 (21)| 00:00:01 |
|* 7 | HASH JOIN | | 1 | 54 | 7750 (21)| 00:00:01 |
| 8 | VIEW | VW_VT_377C5901 | 1 | 30 | 7748 (21)| 00:00:01 |
| 9 | VECTOR GROUP BY | | 1 | 13 | 7748 (21)| 00:00:01 |
| 10 | HASH GROUP BY | | 1 | 13 | 7748 (21)| 00:00:01 |
| 11 | KEY VECTOR USE | :KV0000 | 200K| 2539K| 7748 (21)| 00:00:01 |
|* 12 | TABLE ACCESS INMEMORY FULL| TST_1 | 200M| 1716M| 7697 (21)| 00:00:01 |
| 13 | TABLE ACCESS FULL | SYS_TEMP_0FD9D66FA_57B2B | 1 | 24 | 2 (0)| 00:00:01 |
--------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
5 - filter("NAME2"='50a')
7 - access("ITEM_5"=INTERNAL_FUNCTION("C0") AND "ITEM_6"="C2")
12 - inmemory(SYS_OP_KEY_VECTOR_FILTER("A"."REF_ID",:KV0000))
filter(SYS_OP_KEY_VECTOR_FILTER("A"."REF_ID",:KV0000))
Note
-----
- vector transformation used for this statement
After having such impressive performance I’ve decided to run the query in parallel:
select /*+ parallel(8) */ name, sum(val) from tst_1 a, tst_2 b where a.ref_id = b.ref_id and name2='50a' group by name; Elapsed: 00:01:02.55
Query elapsed time suddenly dropped from 0.17 seconds to the almost 1 minute and 3 seconds. But the second execution runs in 0.6 seconds.
The new plan is:
Execution Plan
----------------------------------------------------------
Plan hash value: 3623951262
-----------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib |
-----------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 29 | 1143 (26)| 00:00:01 | | | |
| 1 | PX COORDINATOR | | | | | | | | |
| 2 | PX SEND QC (RANDOM) | :TQ10001 | 1 | 29 | 1143 (26)| 00:00:01 | Q1,01 | P->S | QC (RAND) |
| 3 | HASH GROUP BY | | 1 | 29 | 1143 (26)| 00:00:01 | Q1,01 | PCWP | |
| 4 | PX RECEIVE | | 1 | 29 | 1143 (26)| 00:00:01 | Q1,01 | PCWP | |
| 5 | PX SEND HASH | :TQ10000 | 1 | 29 | 1143 (26)| 00:00:01 | Q1,00 | P->P | HASH |
| 6 | HASH GROUP BY | | 1 | 29 | 1143 (26)| 00:00:01 | Q1,00 | PCWP | |
|* 7 | HASH JOIN | | 200K| 5664K| 1142 (26)| 00:00:01 | Q1,00 | PCWP | |
| 8 | JOIN FILTER CREATE | :BF0000 | 1 | 20 | 2 (0)| 00:00:01 | Q1,00 | PCWP | |
|* 9 | TABLE ACCESS FULL | TST_2 | 1 | 20 | 2 (0)| 00:00:01 | Q1,00 | PCWP | |
| 10 | JOIN FILTER USE | :BF0000 | 200M| 1716M| 1069 (21)| 00:00:01 | Q1,00 | PCWP | |
| 11 | PX BLOCK ITERATOR | | 200M| 1716M| 1069 (21)| 00:00:01 | Q1,00 | PCWC | |
|* 12 | TABLE ACCESS INMEMORY FULL| TST_1 | 200M| 1716M| 1069 (21)| 00:00:01 | Q1,00 | PCWP | |
-----------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
7 - access("A"."REF_ID"="B"."REF_ID")
9 - filter("NAME2"='50a')
12 - inmemory(SYS_OP_BLOOM_FILTER(:BF0000,"A"."REF_ID"))
filter(SYS_OP_BLOOM_FILTER(:BF0000,"A"."REF_ID"))
Note
-----
- dynamic statistics used: dynamic sampling (level=AUTO)
- Degree of Parallelism is 8 because of hint
We can see a Bloom filter instead of key vector, but this is not the issue. Problem is coming from the “dynamic statistics used: dynamic sampling (level=AUTO)” note.
In 10046 trace file I’ve found nine dynamic sampling queries and one of them was this one:
SELECT /* DS_SVC */ /*+ dynamic_sampling(0) no_sql_tune no_monitoring
optimizer_features_enable(default) no_parallel result_cache(snapshot=3600)
*/ SUM(C1)
FROM
(SELECT /*+ qb_name("innerQuery") */ 1 AS C1 FROM (SELECT /*+
NO_VECTOR_TRANSFORM ORDERED */ "A"."VAL" "ITEM_1","A"."REF_ID" "ITEM_2"
FROM "TST_1" "A") "VW_VTN_377C5901#0", (SELECT /*+ NO_VECTOR_TRANSFORM
ORDERED */ "B"."NAME" "ITEM_3","B"."REF_ID" "ITEM_4" FROM "TST_2" "B" WHERE
"B"."NAME2"='50a') "VW_VTN_EE607F02#1" WHERE ("VW_VTN_377C5901#0"."ITEM_2"=
"VW_VTN_EE607F02#1"."ITEM_4")) innerQuery
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 43.92 76.33 0 5 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 43.92 76.33 0 5 0 0
Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 64 (recursive depth: 1)
Number of plan statistics captured: 1
Rows (1st) Rows (avg) Rows (max) Row Source Operation
---------- ---------- ---------- ---------------------------------------------------
0 0 0 RESULT CACHE 56bn7fg7qvrrw1w8cmanyn3mxr (cr=0 pr=0 pw=0 time=0 us)
0 0 0 SORT AGGREGATE (cr=0 pr=0 pw=0 time=8 us)
0 0 0 HASH JOIN (cr=0 pr=0 pw=0 time=4 us cost=159242 size=2600000 card=200000)
200000000 200000000 200000000 TABLE ACCESS INMEMORY FULL TST_1 (cr=3 pr=0 pw=0 time=53944537 us cost=7132 size=800000000 card=200000000)
0 0 0 TABLE ACCESS FULL TST_2 (cr=0 pr=0 pw=0 time=3 us cost=4 size=9 card=1)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
asynch descriptor resize 1 0.00 0.00
Disk file operations I/O 1 0.00 0.00
CSS initialization 1 0.00 0.00
CSS operation: action 1 0.00 0.00
direct path write temp 6267 0.02 30.37
********************************************************************************
Vector transformation is disabled, inefficient table order is fixed by the ORDERING hint and we are waiting for hash table creation based on huge TST_1 table.
Dynamic statistics feature has been greatly improved in Oracle 12c with the support for joins and group by predicates. This is why we have such join during the parse time. Next document has the”Dynamic Statistics (previously known as dynamic sampling)” section inside: Understanding Optimizer Statistics with Oracle Database 12c where the new functionality is described.
Let’s make a simpler test:
select /*+ parallel(2) */ ref_id, sum(val) from tst_1 a group by ref_id; Execution Plan ---------------------------------------------------------- Plan hash value: 2527371111 --------------------------------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | TQ |IN-OUT| PQ Distrib | --------------------------------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 1000 | 9000 | 7949 (58)| 00:00:01 | | | | | 1 | PX COORDINATOR | | | | | | | | | | 2 | PX SEND QC (RANDOM) | :TQ10001 | 1000 | 9000 | 7949 (58)| 00:00:01 | Q1,01 | P->S | QC (RAND) | | 3 | HASH GROUP BY | | 1000 | 9000 | 7949 (58)| 00:00:01 | Q1,01 | PCWP | | | 4 | PX RECEIVE | | 1000 | 9000 | 7949 (58)| 00:00:01 | Q1,01 | PCWP | | | 5 | PX SEND HASH | :TQ10000 | 1000 | 9000 | 7949 (58)| 00:00:01 | Q1,00 | P->P | HASH | | 6 | HASH GROUP BY | | 1000 | 9000 | 7949 (58)| 00:00:01 | Q1,00 | PCWP | | | 7 | PX BLOCK ITERATOR | | 200M| 1716M| 4276 (21)| 00:00:01 | Q1,00 | PCWC | | | 8 | TABLE ACCESS INMEMORY FULL| TST_1 | 200M| 1716M| 4276 (21)| 00:00:01 | Q1,00 | PCWP | | --------------------------------------------------------------------------------------------------------------------------- Note ----- - dynamic statistics used: dynamic sampling (level=AUTO) - Degree of Parallelism is 2 because of hint
We can see a “dynamic statistics used” note again. It’s a simple query without predicates with the single table with pretty accurate statistics. From my point of view, here is no reason for dynamic sampling at all.
Automatic dynamic sampling was introduced in 11G Release 2. Description of this feature can be found in this document: Dynamic sampling and its impact on the Optimizer.
“From Oracle Database 11g Release 2 onwards the optimizer will automatically decide if dynamic sampling will be useful and what dynamic sampling level will be used for SQL statements executed in parallel. This decision is based on size of the tables in the statement and the complexity of the predicates”.
Looks like algorithm has been changed in 12c and dynamic sampling is triggered in a broader set of use cases.
This behavior can be disabled at statement, session or system level using the fix control for the bug 7452863. For example,
ALTER SESSION SET “_fix_control”=’7452863:0′;
Summary
Dynamic statistics has been enhanced in Oracle 12c, but this can lead to a longer parse time.
Automatic dynamic statistics is used more often in 12c which can lead to a parse time increase in the more cases than before.
Oracle Database Consulting Services
Ready to optimize your Oracle Database for the future?
Share this
- Technical Track (816)
- Oracle (488)
- Database (229)
- MySQL (144)
- Cloud (133)
- Microsoft SQL Server (124)
- Open Source (84)
- Google Cloud (82)
- Microsoft Azure (67)
- Amazon Web Services (AWS) (63)
- Big Data (50)
- Cassandra (44)
- Google Cloud Platform (44)
- DevOps (38)
- Linux (28)
- Pythian (27)
- PostgreSQL (26)
- Podcasts (25)
- Site Reliability Engineering (23)
- Performance (22)
- Docker (21)
- Oracle E-Business Suite (21)
- DBA (18)
- Oracle Cloud Infrastructure (OCI) (18)
- MongoDB (17)
- Security (17)
- Hadoop (16)
- BigQuery (15)
- Amazon RDS (14)
- Automation (14)
- Exadata (14)
- Oracleebs (14)
- Snowflake (14)
- Ansible (13)
- Oracle Database (13)
- Oracle Exadata (13)
- ASM (12)
- Data (12)
- LLM (12)
- Artificial Intelligence (AI) (11)
- GenAI (11)
- Kubernetes (11)
- Machine Learning (11)
- Advanced Analytics (10)
- Datascape Podcast (10)
- Oracle Applications (10)
- Replication (10)
- Authentication, SSO and MFA (8)
- ChatGPT (8)
- Cloud Migration (8)
- Infrastructure (8)
- Monitoring (8)
- Percona (8)
- Analytics (7)
- Apache (7)
- Apache Cassandra (7)
- Data Governance (7)
- High Availability (7)
- Mariadb (7)
- Microsoft Azure SQL Database (7)
- Myrocks (7)
- Oracle EBS (7)
- Python (7)
- Rman (7)
- SAP (7)
- Series (7)
- AWR (6)
- Airflow (6)
- Apache Beam (6)
- Data Guard (6)
- Innodb (6)
- Migration (6)
- Oracle Enterprise Manager (OEM) (6)
- Orchestrator (6)
- RocksDB (6)
- Azure Synapse Analytics (5)
- Covid-19 (5)
- Data Enablement (5)
- Disaster Recovery (5)
- Microsoft (5)
- Performance Tuning (5)
- Scala (5)
- Serverless (5)
- Cloud Security (4)
- Cloud Spanner (4)
- CockroachDB (4)
- Data Management (4)
- Data Pipeline (4)
- Data Security (4)
- Data Strategy (4)
- Data Visualization (4)
- Databases (4)
- Dataflow (4)
- Generative AI (4)
- Google (4)
- Google BigQuery (4)
- Oracle Autonomous Database (Adb) (4)
- Oracle Cloud (4)
- Oracle Enterprise Manager (4)
- Redhat (4)
- Ssl (4)
- Windows (4)
- Xtrabackup (4)
- Amazon Relational Database Service (Rds) (3)
- Apex (3)
- Cloud Database (3)
- Cloud FinOps (3)
- Data Analytics (3)
- Data Migrations (3)
- Database Migration (3)
- Digital Transformation (3)
- ERP (3)
- Google Chrome (3)
- Google Cloud Sql (3)
- Google Workspace (3)
- Heterogeneous Database Migration (3)
- Oracle Live Sql (3)
- Oracle Rac (3)
- Perl (3)
- Power Bi (3)
- Prometheus (3)
- Remote Teams (3)
- Slob (3)
- Tensorflow (3)
- Terraform (3)
- Amazon Data Migration Service (2)
- Amazon Ec2 (2)
- Anisble (2)
- Apache Flink (2)
- Apache Kafka (2)
- Apexexport (2)
- Ashdump (2)
- Aurora (2)
- Azure Data Factory (2)
- Cloud Armor (2)
- Cloud Data Fusion (2)
- Cloud Hosting (2)
- Cloud Infrastructure (2)
- Cloud Shell (2)
- Cloud Sql (2)
- Conferences (2)
- Cosmos Db (2)
- Cosmosdb (2)
- Cost Management (2)
- Data Discovery (2)
- Data Integration (2)
- Data Quality (2)
- Data Streaming (2)
- Database Administrator (2)
- Database Consulting (2)
- Database Monitoring (2)
- Database Performance (2)
- Database Troubleshooting (2)
- Dataguard (2)
- Dataops (2)
- Enterprise Data Platform (EDP) (2)
- Events (2)
- Fusion Middleware (2)
- Gemini (2)
- Graphite (2)
- Infrastructure As Code (2)
- Innodb Cluster (2)
- Innodb File Structure (2)
- Innodb Group Replication (2)
- Liquibase (2)
- NLP (2)
- Nosql (2)
- Oracle Data Guard (2)
- Oracle Datase (2)
- Oracle Flashback (2)
- Oracle Forms (2)
- Oracle Installation (2)
- Oracle Io Testing (2)
- Podcast (2)
- Rdbms (2)
- Redshift (2)
- Remote DBA (2)
- Remote Sre (2)
- S3 (2)
- Single Sign-On (2)
- Webinars (2)
- X5 (2)
- AI (1)
- Actifio (1)
- Adop (1)
- Advanced Data Services (1)
- Afd (1)
- Alloydb (1)
- Amazon (1)
- Amazon Aurora Backtrack (1)
- Amazon Efs (1)
- Amazon Redshift (1)
- Amazon S3 (1)
- Amazon Sagemaker (1)
- Amazon Vpc Flow Logs (1)
- Analysis (1)
- Analytical Models (1)
- Anthos (1)
- Application Migration (1)
- Ash (1)
- Asmlib (1)
- Atp (1)
- Autonomous (1)
- Awr Data Mining (1)
- Awr Mining (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)
- Business Intelligence (1)
- Chown (1)
- Chrome Security (1)
- Cloud Browser (1)
- Cloud Build (1)
- Cloud Consulting (1)
- Cloud Cost Optimization (1)
- Cloud Data Warehouse (1)
- Cloud Database Management (1)
- Cloud Dataproc (1)
- Cloud Foundry (1)
- Cloud Networking (1)
- Cloud SQL Replica (1)
- Cloud Scheduler (1)
- Cloud Services (1)
- Cloud Strategies (1)
- Compliance (1)
- Conversational AI (1)
- Cyber Security (1)
- Data Analysis (1)
- Data Analytics Platform (1)
- Data Box (1)
- Data Classification (1)
- Data Cleansing (1)
- Data Encryption (1)
- Data Engineering (1)
- Data Estate (1)
- Data Insights (1)
- Data Integrity (1)
- Data Leader (1)
- Data Lifecycle Management (1)
- Data Lineage (1)
- Data Masking (1)
- Data Mesh (1)
- Data Migration (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 (1)
- Database Consultant (1)
- Database Link (1)
- Database Management (1)
- Database Migrations (1)
- Database Modernization (1)
- Database Provisioning (1)
- Database Provisioning Failed (1)
- Database Replication (1)
- Database Schemas (1)
- Database Upgrade (1)
- Databricks (1)
- Datascape 59 (1)
- DeepSeek (1)
- Docker-Composer (1)
- Duet AI (1)
- Edp (1)
- Etl (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 Inferences (1)
- Graph Theory (1)
- GraphQL (1)
- Health Check (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)
- Neo4J (1)
- Newsroom (1)
- Nifi (1)
- OPEX (1)
- Odbcs (1)
- Odbs (1)
- On-Premises (1)
- Open Source Database (1)
- Ora-01852 (1)
- Ora-7445 (1)
- Oracle Cursor (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)
- Perfomrance (1)
- Performance Schema (1)
- Policy (1)
- Prompt Engineering (1)
- Public Cloud (1)
- Pythian News (1)
- Rdb (1)
- Replication Error (1)
- Retail (1)
- SAP HANA Cloud (1)
- Securing Sql Server (1)
- Serverless Computing (1)
- Sso (1)
- Tenserflow (1)
- Teradata (1)
- Vertex AI (1)
- Videos (1)
- Workspace Security (1)
- Xbstream (1)
- August 2025 (1)
- July 2025 (3)
- June 2025 (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 (9)
- October 2023 (11)
- September 2023 (9)
- 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