Share this
Query Statspack's "SQL ordered by" Sections Over a Time Period
by Jure Bratina on Aug 25, 2020 12:00:00 AM
An important note in case you want to compare the results with Statspack reports
Testing the script by comparing its output to regular Statspack reports (created by running $ORACLE_HOME/rdbms/admin/spreport.sql or sprepins.sql), I noticed that sometimes the numbers in the "SQL ordered by" sections didn't match up. Examples include SQLs reported by my script, but not by Statspack reports. This even happened with Statspack reports reporting the same SQL (same hash value) multiple times with different runtime statistics in the same "SQL ordered by" section. The root cause of those anomalies is described in the MOS note "Statspack Reports Show Different Results In 'SQL ordered by ...' When Taken At Different Times with Same Snapid (Doc ID 2258762.1)": "When more than one statspack reports are taken repeatedly in the same session by non-perfstat user, some data might get mixed up in the temporary table used by the reporting script, and the result may get corrupted." Not connecting as the owner of the Statspack repository (usually PERFSTAT) when generating multiple consecutive snapshots looping over a snapshot range causes this problem. The same was true also when creating a single Statspack report. The takeaway is to always connect as the Statspack repository owner when running spreport.sql, especially if you use any helper scripts which generate Statspack reports for a series of snapshots.Usage
Starting the script
Let's see the script in action analyzing a sample Swingbench run on a sandbox 2 node RAC database. When run, the script produces a wide output, so I suggest spooling it to a file for easier viewing/plotting:SQL> spool top_sqls.txt SQL> @statspack_top_sqls.sql List SQL by [elapsed_time | cpu_time | buffer_gets | disk_reads | executions | parse_calls | max_sharable_mem | max_version_count | cluster_wait_time]: Enter a value - default "elapsed_time" :First, we specify which category we want the SQLs to be ordered by. We can choose one of the above-listed possibilities, which are the same categories the "SQL ordered by" Statspack report's sections display. The script reports the same SQLs in the same order as they appear in the selected Statspack report category. Suppose we want to order SQLs by "cpu_time," and the corresponding Statspack report lists 10 SQLs in the "SQL ordered by CPU" section. The script lists the same ones. However, the added benefit of the script is that it reports values, which the Statspack report doesn't display. For example, the "SQL ordered by CPU" Statspack report section doesn't display the "Physical Reads" statistic. Instead, it's listed in the "SQL ordered by Elapsed time" section. If an SQL isn't qualified to display in the "SQL ordered by Elapsed time" section, we won't get those values from the Statspack report. Next, we provide the DBID and instance number we want to analyze. If we don't provide an instance number, the script considers all those present in the repository:
Instances in this Statspack schema ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ DB Id Inst Num DB Name Instance Host ----------- -------- ------------ ------------ -------------------------------- 1558102526 1 ORCL orcl1 ol7-122-rac1.localdomain 1558102526 2 ORCL orcl2 ol7-122-rac2.localdomain Enter DBID to analyze - default "1558102526" : Enter instance number or "all" to analyze all instancs for DBID = 1558102526 - default "all" :Finally, we specify the time range we'd like to analyze:
Enter begin time for report [DD-MON-YYYY HH24:MI] - default "30-APR-2020 10:54" : 15-FEB-2020 12:30 Enter end time for report [DD-MON-YYYY HH24:MI] - default "30-APR-2020 22:54" : 15-FEB-2020 13:00
Script output
Let's check what the script output looks like on an example where SQLs are ordered by "elapsed_time." For reference, a file containing the whole spool can be obtained here, and two Statspack reports covering the snapshots discussed below are here and here. Since the original spool file contains 280 lines, I'm showing an abbreviated version of the first eight columns. The full output lists SQLs between each snapshot. As we didn't specify which instance number we're interested in, both instances are considered. Additionally, we see it's normal and expected, that consecutive snapshots don't have consecutive numbers. Snapshots 4 and 21 are two consecutive snapshots on instance 1, as we can confirm by checking their snap time. The other columns are self-explanatory:INSTANCE_NUMBER B_SNAP_ID E_SNAP_ID B_SNAP_TIME E_SNAP_TIME INTERVAL_MIN DBTIMEMIN AAS --------------- ---------- ---------- ------------------ ------------------ ------------ ---------- ---------- 1 1 2 15-FEB-20 12:30:00 15-FEB-20 12:40:00 10 2.30 0.23 <removed 16 lines listing SQLs> 2 3 15-FEB-20 12:40:00 15-FEB-20 12:50:00 10 1.60 0.16 <removed 25 lines listing SQLs> 3 4 15-FEB-20 12:50:00 15-FEB-20 13:00:00 10 1.55 0.15 <etc> 4 21 15-FEB-20 13:00:00 15-FEB-20 13:10:00 10 1.66 0.17 21 22 15-FEB-20 13:10:00 15-FEB-20 13:20:00 10 1.30 0.13 22 23 15-FEB-20 13:20:00 15-FEB-20 13:30:00 10 1.18 0.12 2 11 12 15-FEB-20 12:30:00 15-FEB-20 12:40:00 10 3.81 0.38 12 13 15-FEB-20 12:40:00 15-FEB-20 12:50:00 10 2.70 0.27 13 14 15-FEB-20 12:50:00 15-FEB-20 13:00:00 10 2.50 0.25 14 15 15-FEB-20 13:00:00 15-FEB-20 13:10:00 10 2.94 0.29 15 16 15-FEB-20 13:10:00 15-FEB-20 13:20:00 10 2.18 0.22 16 17 15-FEB-20 13:20:00 15-FEB-20 13:30:00 10 1.98 0.20Let's check an excerpt of the output for snapshots 1 to 2 and 2 to 3. Apart from the "HV" column (SQL old hash value), the other columns are self-explanatory. For blog post brevity, I'm showing only the first 10 SQLs per snapshot pair.
B_SNAP_ID E_SNAP_ID HV ELAPSED_TIME_SEC EXECUTIONS ELAPSED_PER_EXEC_SEC PERCENT_OF_DBTIME_USED CPU_TIME_SEC CPU_TIME_MS_PER_EXEC PHYSICAL_READS PHYSICAL_READS_PER_EXECUTION BUFFER_GETS GETS_PER_EXECUTION ROWS_PROCESSED ROWS_PROCESSED_PER_EXECUTION PARSE_CALLS MAX_SHARABLE_MEM_KB LAST_SHARABLE_MEM_KB MAX_VERSION_COUNT LAST_VERSION_COUNT DELTA_VERSION_COUNT CLUSTER_WAIT_TIME_SEC CWT_PERCENT_OF_ELAPSED_TIME AVG_HARD_PARSE_TIME_MS MODULE SQL_TEXT ---------- ---------- ---------- ---------------- ---------- -------------------- ---------------------- ------------ -------------------- -------------- ---------------------------- ----------- ------------------ -------------- ---------------------------- ----------- ------------------- -------------------- ----------------- ------------------ ------------------- --------------------- --------------------------- ---------------------- ------------------------------------------------------------ --------------------------------------------------------------------------- 1 2 3565022785 80,55 483 ,17 58,47 14,63 30,3 5860 12,13 261329 541,05 483 1 483 55,39 55,39 1 1 1 13,67 16,97 JDBC Thin Client BEGIN :1 := orderentry.neworder(:2 ,:3 ,:4 ); END; 2319948924 55,8 5931 ,01 40,51 7,69 1,3 4614 ,78 205925 34,72 26467 4,46 1 47,44 47,44 1 1 1 9,38 16,8 New Order SELECT PRODUCTS.PRODUCT_ID, PRODUCT_NAME, PRODUCT_DESCRIPTION, C 1852190137 14,22 1024 ,01 10,32 7,75 7,57 394 ,38 131100 128,03 1024 1 1025 55,38 55,38 1 1 1 2,65 18,61 BEGIN :1 := orderentry.browseproducts(:2 ,:3 ,:4 ); END; 1113394757 8,17 12332 0 5,93 2,97 ,24 336 ,03 124291 10,08 172648 14 1 43,41 43,41 1 1 1 2,17 26,55 Browse Products SELECT PRODUCTS.PRODUCT_ID, PRODUCT_NAME, PRODUCT_DESCRIPTION, C 4194254847 6,4 483 ,01 4,64 ,84 1,73 396 ,82 7760 16,07 483 1 1 47,64 47,64 1 1 1 1,26 19,72 New Order INSERT INTO ORDERS ( ORDER_ID, ORDER_DATE, ORDER_MODE, CUSTOMER_ 1283549268 4,55 169 ,03 3,3 ,89 5,28 262 1,55 6188 36,62 169 1 169 59,46 59,46 1 1 1 ,83 18,16 BEGIN :1 := orderentry.newcustomer(:2 ,:3 ,:4 ,:5 ,:6 ,:7 ,:8 ,: 2588369535 4,21 24 ,18 3,06 1,12 46,55 76 3,17 13104 546 24 1 24 55,38 55,38 1 1 1 2,21 52,52 BEGIN :1 := orderentry.SalesRepsQuery(:2 ,:3 ,:4 ); END; 4212635381 4,18 24 ,17 3,04 1,09 45,39 76 3,17 13104 546 737 30,71 1 35,51 35,51 1 1 1 2,21 52,9 Sales Rep Query SELECT TT.ORDER_TOTAL, TT.SALES_REP_ID, TT.ORDER_DATE, CUSTOMERS 4219272024 3,97 1396 0 2,88 ,86 ,62 167 ,12 19979 14,31 1396 1 1 27,42 27,42 1 1 1 1,15 28,85 New Order INSERT INTO ORDER_ITEMS ( ORDER_ID, LINE_ITEM_ID, PRODUCT_ID, UN 2835506982 3,74 173 ,02 2,71 ,57 3,32 255 1,47 3579 20,69 173 1 173 55,38 55,38 1 1 1 ,39 10,53 BEGIN :1 := orderentry.browseandupdateorders(:2 ,:3 ,:4 ); END; (..) 2 3 3565022785 46,93 956 ,05 48,79 18,87 19,73 1138 1,19 511742 535,29 956 1 957 113,27 113,27 2 2 1 15,91 33,89 JDBC Thin Client BEGIN :1 := orderentry.neworder(:2 ,:3 ,:4 ); END; 2319948924 22,85 11550 0 23,75 7,52 ,65 487 ,04 402425 34,84 51879 4,49 0 47,44 47,44 1 1 0 9 39,39 New Order SELECT PRODUCTS.PRODUCT_ID, PRODUCT_NAME, PRODUCT_DESCRIPTION, C 1852190137 15,35 2158 ,01 15,95 11,98 5,55 164 ,08 274493 127,2 2158 1 2157 113,25 113,25 2 2 1 1,32 8,63 BEGIN :1 := orderentry.browseproducts(:2 ,:3 ,:4 ); END; 1283549268 6,36 380 ,02 6,61 1,65 4,33 303 ,8 13726 36,12 380 1 380 121,42 121,42 2 2 1 1,42 22,26 BEGIN :1 := orderentry.newcustomer(:2 ,:3 ,:4 ,:5 ,:6 ,:7 ,:8 ,: 2835506982 6 377 ,02 6,24 1,03 2,72 448 1,19 7218 19,15 377 1 377 113,27 113,27 2 2 1 ,72 12,06 BEGIN :1 := orderentry.browseandupdateorders(:2 ,:3 ,:4 ); END; 1822227481 5,32 7742 0 5,53 1,26 ,16 259 ,03 23226 3 7742 1 0 31,5 31,5 1 1 0 1,5 28,14 New Order SELECT CUSTOMER_ID, CUST_FIRST_NAME, CUST_LAST_NAME, NLS_LANGUAG 4194254847 4,69 957 0 4,87 1,22 1,28 150 ,16 14371 15,02 957 1 0 47,64 47,64 1 1 0 1,76 37,54 New Order INSERT INTO ORDERS ( ORDER_ID, ORDER_DATE, ORDER_MODE, CUSTOMER_ 3463613875 4,61 380 ,01 4,79 ,62 1,62 298 ,78 5844 15,38 380 1 0 59,63 59,63 1 1 0 ,81 17,49 Update Customer Details INSERT INTO CUSTOMERS ( CUSTOMER_ID , CUST_FIRST_NAME , CUST_LAS 1113394757 4,07 25794 0 4,23 3,28 ,13 0 0 260084 10,08 361116 14 0 43,41 43,41 1 1 0 ,41 9,98 Browse Products SELECT PRODUCTS.PRODUCT_ID, PRODUCT_NAME, PRODUCT_DESCRIPTION, C 4219272024 3,89 2945 0 4,04 1,43 ,49 76 ,03 42277 14,36 2945 1 0 27,42 27,42 1 1 0 1,77 45,53 New Order INSERT INTO ORDER_ITEMS ( ORDER_ID, LINE_ITEM_ID, PRODUCT_ID, UN (..)Let's check how a regular Statspack report covering snapshot IDs 1 to 2 looks compared to the above output. The report's "SQL ordered by Elapsed time" section reports the same SQLs in the same order as in the above excerpt. The difference is that the latter displays attributes from other "SQL ordered by" sections which are not present in the below output:
Snapshot Snap Id Snap Time ~~~~~~~~ ---------- ------------------ Begin Snap: 1 15-Feb-20 12:30:00 End Snap: 2 15-Feb-20 12:40:00 Elapsed: 10.00 (mins) DB time: 2.30 (mins) Load Profile Per Second ~~~~~~~~~~~~ ------------------ DB time(s): 0.2 SQL ordered by Elapsed time for DB: ORCL Instance: orcl1 Snaps: 1 -2 -> Total DB Time (s): 138 -> Captured SQL accounts for 153.3% of Total DB Time -> SQL reported below exceeded 1.0% of Total DB Time Elapsed Elap per CPU Old Time (s) Executions Exec (s) %Total Time (s) Physical Reads Hash Value ---------- ------------ ---------- ------ ---------- --------------- ---------- 80.55 483 0.17 58.5 14.63 5,860 3565022785 Module: JDBC Thin Client BEGIN :1 := orderentry.neworder(:2 ,:3 ,:4 ); END; 55.80 5,931 0.01 40.5 7.69 4,614 2319948924 Module: New Order SELECT PRODUCTS.PRODUCT_ID, PRODUCT_NAME, PRODUCT_DESCRIPTION, C ATEGORY_ID, WEIGHT_CLASS, WARRANTY_PERIOD, SUPPLIER_ID, PRODUCT_ STATUS, LIST_PRICE, MIN_PRICE, CATALOG_URL, QUANTITY_ON_HAND FRO M PRODUCTS, INVENTORIES WHERE PRODUCTS.CATEGORY_ID = :B3 AND INV 14.22 1,024 0.01 10.3 7.75 394 1852190137 BEGIN :1 := orderentry.browseproducts(:2 ,:3 ,:4 ); END; 8.17 12,332 0.00 5.9 2.97 336 1113394757 Module: Browse Products SELECT PRODUCTS.PRODUCT_ID, PRODUCT_NAME, PRODUCT_DESCRIPTION, C ATEGORY_ID, WEIGHT_CLASS, WARRANTY_PERIOD, SUPPLIER_ID, PRODUCT_ STATUS, LIST_PRICE, MIN_PRICE, CATALOG_URL, QUANTITY_ON_HAND FRO M PRODUCTS, INVENTORIES WHERE PRODUCTS.PRODUCT_ID = :B2 AND INVE 6.40 483 0.01 4.6 0.84 396 4194254847 Module: New Order INSERT INTO ORDERS ( ORDER_ID, ORDER_DATE, ORDER_MODE, CUSTOMER_ ID, ORDER_STATUS, WAREHOUSE_ID, DELIVERY_TYPE, DELIVERY_ADDRESS_ ID, COST_OF_DELIVERY, WAIT_TILL_ALL_AVAILABLE, CUSTOMER_CLASS, C ARD_ID, INVOICE_ADDRESS_ID ) VALUES ( ORDERS_SEQ.NEXTVAL + :B8 , 4.55 169 0.03 3.3 0.89 262 1283549268 BEGIN :1 := orderentry.newcustomer(:2 ,:3 ,:4 ,:5 ,:6 ,:7 ,:8 ,: 9 ,:10 ); END; 4.21 24 0.18 3.1 1.12 76 2588369535 BEGIN :1 := orderentry.SalesRepsQuery(:2 ,:3 ,:4 ); END; 4.18 24 0.17 3.0 1.09 76 4212635381 Module: Sales Rep Query SELECT TT.ORDER_TOTAL, TT.SALES_REP_ID, TT.ORDER_DATE, CUSTOMERS .CUST_FIRST_NAME, CUSTOMERS.CUST_LAST_NAME FROM (SELECT ORDERS.O RDER_TOTAL, ORDERS.SALES_REP_ID, ORDERS.ORDER_DATE, ORDERS.CUSTO MER_ID, RANK() OVER (ORDER BY ORDERS.ORDER_TOTAL DESC) SAL_RANK 3.97 1,396 0.00 2.9 0.86 167 4219272024 Module: New Order INSERT INTO ORDER_ITEMS ( ORDER_ID, LINE_ITEM_ID, PRODUCT_ID, UN IT_PRICE, QUANTITY, GIFT_WRAP, CONDITION, ESTIMATED_DELIVERY ) V ALUES ( :B4 , :B3 , :B2 , :B1 , 1, 'None', 'New', (SYSDATE + 3) ) 3.74 173 0.02 2.7 0.57 255 2835506982 BEGIN :1 := orderentry.browseandupdateorders(:2 ,:3 ,:4 ); END; (..)
Final notes
- Oracle's sprepins.sql script has a /*+ first_rows */ hint in the inline view containing analytical functions used to compute the current and previous row values from the stats$sql_summary table. The hint is present, but not enabled in statspack_top_sqls.sql. If, for some reason, you need to re-enable it, just search for and enable it in the script (or use its alternative first_rows(0) ).
- I’ve seen the script fail with errors like “ORA-00936: missing expression,” or “ORA-01722: invalid number” when used on databases running with cursor_sharing=FORCE. To avoid the error, I included the /*+ cursor_sharing_exact*/ hint in the script’s SELECT statement. Setting cursor_sharing=EXACT at the session-level is also a valid alternative.
Share this
- Technical Track (967)
- Oracle (410)
- 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)
- Apache Cassandra (9)
- ChatGPT (9)
- Data Guard (9)
- Infrastructure (9)
- Oracle Applications (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 (1)
- 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