Ejemplos de uso de Select AI

Explore la integración de Select AI de Oracle con varios proveedores de IA compatibles para generar, ejecutar y explicar SQL a partir de peticiones de datos en lenguaje natural o chatear con el LLM.

Ejemplo: selección de acciones de AI

Estos ejemplos ilustran acciones comunes de Select AI.

En el siguiente ejemplo se muestran acciones como runsql (valor por defecto), showsql, narrate, chat y explainsql que puede realizar con SELECT AI. En estos ejemplos se utiliza el esquema sh con el proveedor de AI y los atributos de perfil definidos en la función DBMS_CLOUD_AI.CREATE_PROFILE.

SQL> select ai how many customers exist;
 
CUSTOMER_COUNT
--------------
         55500
 
SQL> select ai showsql how many customers exist;
 
RESPONSE
----------------------------------------------------
SELECT COUNT(*) AS total_customers
FROM SH.CUSTOMERS
 
 
SQL> select ai narrate how many customers exist;
 
RESPONSE
------------------------------------------------------
There are a total of 55,500 customers in the database.
 
SQL> select ai chat how many customers exist;
 
RESPONSE
--------------------------------------------------------------------------------
It is impossible to determine the exact number of customers that exist as it con
stantly changes due to various factors such as population growth, new businesses
, and customer turnover. Additionally, the term "customer" can refer to individu
als, businesses, or organizations, making it difficult to provide a specific num
ber.


SQL> select ai explainsql how many customers in San Francisco are married;
 
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS customer_count
FROM SH.CUSTOMERS AS c
WHERE c.CUST_STATE_PROVINCE = 'San Francisco' AND c.CUST_MARITAL_STATUS = 'Married';
 
Explanation:
- We use the 'SH' table alias for the 'CUSTOMERS' table for better readability.
- The query uses the 'COUNT(*)' function to count the number of rows that match the given conditions.
- The 'WHERE' clause is used to filter the results:
  - 'c.CUST_STATE_PROVINCE = 'San Francisco'' filters customers who have 'San Francisco' as their state or province.
  - 'c.CUST_MARITAL_STATUS = 'Married'' filters customers who have 'Married' as their marital status.
The result of this query will give you the count of customers in San Francisco who are married, using the column alias 'customer_count' for the result.
 
Remember to adjust the table and column names based on your actual schema if they differ from the example.
 
Feel free to ask if you have more questions related to SQL or database in general.

Ejemplo: selección de IA con OCI Generative AI

Estos ejemplos muestran cómo puede acceder a OCI Generative AI mediante su clave de API de OCI o entidad de recurso, crear un perfil de IA y generar, ejecutar y explicar SQL a partir de peticiones de datos en lenguaje natural o chat mediante los LLM de OCI Generative AI.

Nota

Si no especifica el parámetro model_name, OCI Generative AI utiliza el modelo por defecto según la tabla de Select your AI Provider and LLMs. Para obtener más información sobre los parámetros, consulte Atributos de perfil.
-- Create Credential with OCI API key
--
BEGIN                                                                         
  DBMS_CLOUD.CREATE_CREDENTIAL(                                               
    credential_name => 'GENAI_CRED',                                          
    user_ocid       => 'ocid1.user.oc1..aaaa...',
    tenancy_ocid    => 'ocid1.tenancy.oc1..aaaa...',
    private_key     => '<your_api_key>',
    fingerprint     => '<your_fingerprint>'      
  );                                                                          
END;                                                                         
/
 
--
-- Create AI profile
--
BEGIN                                                                        
  DBMS_CLOUD_AI.CREATE_PROFILE(                                              
      profile_name =>'GENAI',                                                             
      attributes   =>'{"provider": "oci",                                                                   
        "credential_name": "GENAI_CRED",
		"object_list": [{"owner": "SH", "name": "customers"},                
                            {"owner": "SH", "name": "countries"},                
                            {"owner": "SH", "name": "supplementary_demographics"},
                           {"owner": "SH", "name": "profits"},                  
                           {"owner": "SH", "name": "promotions"},               
                           {"owner": "SH", "name": "products"}]
       }');                                                                  
END;                                                                         
/   
   
PL/SQL procedure successfully completed.
   
--
-- Enable AI profile in current session
--
EXEC DBMS_CLOUD_AI.SET_PROFILE('GENAI');
   
PL/SQL procedure successfully completed.
   
--
-- Get Profile in current session
--
SELECT DBMS_CLOUD_AI.get_profile() from dual;
 
DBMS_CLOUD_AI.GET_PROFILE()
--------------------------------------------------------------------------------
"GENAI"
  
--
-- Use AI
--  
SQL> select ai how many customers exist;
Number of Customers
-------------------
              55500

SQL> select ai how many customers in San Francisco are married;
COUNT(DISTINCTC."CUST_ID")
--------------------------
                        28

SQL> select ai showsql how many customers in San Francisco are married;
RESPONSE                                                                                                                                                                                             
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SELECT COUNT(DISTINCT c."CUST_ID")
FROM "SH"."CUSTOMERS" c
JOIN "SH"."COUNTRIES" co ON c."COUNTRY_ID" = co."COUNTRY_ID"
WHERE c."CUST_CITY" = 'San Francisco' AND c."CUST_MARITAL_STATUS" = 'married'

SQL> select ai explainsql how many customers in San Francisco are married;
RESPONSE                                                                                                                                                          
Here is the Oracle SQL query to find the number of customers in San Francisco who are married:
```
SELECT COUNT(*)
FROM "SH"."CUSTOMERS" c
WHERE c."CUST_CITY" = 'San Francisco'
AND c."CUST_MARITAL_STATUS" = 'Married';
```
Explanation:
* We use the `COUNT(*)` aggregate function to count the number of rows that match the conditions.
* We specify the table alias `c` for the `"SH"."CUSTOMERS"` table to make the query more readable.
* We use the `WHERE` clause to filter the rows based on two conditions:
    + `c."CUST_CITY" = 'San Francisco'`: We filter the rows where the customer's city is San Francisco.
    + `c."CUST_MARITAL_STATUS" = 'Married'`: We filter the rows where the customer's marital status is Married.
* The double quotes around the table and column names are used to make the query case-sensitive, as required in Oracle SQL.
Note: The column names and table names are assumed to be case-sensitive, so we enclose them in double quotes. If the column names and table names are not case-sensitive, you can remove the double quotes.
Collapse
 This snippet was truncated for display; see it in full

SQL> select ai narrate how many customers in San Francisco are married;

RESPONSE                                                
--------------------------------------------------------
There are 28 customers in San Francisco who are married.


SQL> select ai chat what is Autonomous Database;

RESPONSE                                                                                                                                                                                                                                                                                                    
An Autonomous Database is a type of database that uses artificial intelligence (AI) and machine learning (ML) to automate many of the administrative and maintenance tasks typically performed by a database administrator (DBA). This allows the database to manage itself, without human intervention, to a large extent.
Autonomous databases are designed to be self-driving, self-securing, and self-repairing, which means they can:
1. **Automate administrative tasks**: Such as provisioning, patching, upgrading, and tuning, which frees up DBAs to focus on higher-level tasks.
2. **Optimize performance**: By automatically adjusting parameters, indexing, and caching to ensure optimal performance and efficiency.
3. **Detect and respond to security threats**: By using AI-powered security tools to identify and respond to potential security threats in real-time.
4. **Heal itself**: By automatically detecting and repairing errors, corruption, or other issues that may arise.
5. **Scale up or down**: To match changing workload demands, without the need for manual intervention.
The benefits of Autonomous Databases include:
1. **Increased efficiency**: By automating routine tasks, DBAs can focus on more strategic activities.
2. **Improved performance**: Autonomous databases can optimize performance in real-time, leading to faster query response times and better overall system performance.
3. **Enhanced security**: AI-powered security tools can detect and respond to threats more quickly and effectively than human administrators.
4. **Reduced costs**: By minimizing the need for manual intervention, Autonomous Databases can help reduce labor costs and improve resource utilization.
5. **Improved reliability**: Autonomous Databases can detect and repair errors more quickly, reducing downtime and improving overall system reliability.
Oracle Autonomous Database is a popular example of an Autonomous Database, which was introduced in 2018. Other vendors, such as Amazon, Microsoft, and Google, also offer Autonomous Database services as part of their cloud offerings.
In summary, Autonomous Databases are designed to be self-managing, self-optimizing, and self-healing, which can lead to improved performance, security, and efficiency, while reducing costs and administrative burdens.

--
--Drop the profile
--
EXEC DBMS_CLOUD_AI.DROP_PROFILE('GENAI');
  
PL/SQL procedure successfully completed.

Ejemplo: selección de IA con entidad de recurso de IA generativa de OCI

Para utilizar la entidad de recurso con OCI Generative AI, el administrador del arrendamiento de Oracle Cloud Infrastructure debe otorgar acceso a los recursos de Generative AI a un grupo dinámico. Consulte Cumplimiento de requisitos para utilizar la entidad de recurso con Autonomous Database para proporcionar acceso a un grupo dinámico.

Defina las políticas necesarias para obtener acceso a todos los recursos de IA generativa. Consulte Getting Access to Generative AI para obtener más información sobre las políticas de Generative AI.
  • Para obtener acceso a todos los recursos de IA generativa de todo el arrendamiento, utilice la siguiente política:

    allow group <your-group-name> to manage generative-ai-family in tenancy
  • Para obtener acceso a todos los recursos de IA generativa del compartimento, utilice la siguiente política:

    allow group <your-group-name> to manage generative-ai-family in compartment <your-compartment-name>

Conéctese como administrador y active la entidad de recurso de OCI. Consulte Procedimiento ENABLE_PRINCIPAL_AUTH para configurar los parámetros.

Nota

OCI Generative AI utiliza meta.llama-3-70b-instruct como modelo por defecto si no especifica model. Para obtener más información sobre los parámetros, consulte Atributos de perfil.
-- Connect as Administrator user and enable OCI resource principal.
BEGIN
  DBMS_CLOUD_ADMIN.ENABLE_PRINCIPAL_AUTH(provider  => 'OCI');
END;
/
 
--
-- Create AI profile
--
BEGIN                                                                        
  DBMS_CLOUD_AI.CREATE_PROFILE(                                              
      profile_name =>'GENAI',                                                             
      attributes =>'{"provider": "oci",                                                                   
        "credential_name": "OCI$RESOURCE_PRINCIPAL",
		"object_list": [{"owner": "SH", "name": "customers"},                
                            {"owner": "SH", "name": "countries"},                
                            {"owner": "SH", "name": "supplementary_demographics"},
                           {"owner": "SH", "name": "profits"},                  
                           {"owner": "SH", "name": "promotions"},               
                           {"owner": "SH", "name": "products"}]
       }');                                                                  
END;                                                                         
/
   
PL/SQL procedure successfully completed.
   
--
-- Enable AI profile in current session
--
EXEC DBMS_CLOUD_AI.SET_PROFILE('GENAI');
   
PL/SQL procedure successfully completed.

--
-- Get Profile in current session
--
SELECT DBMS_CLOUD_AI.get_profile() from dual;
 
DBMS_CLOUD_AI.GET_PROFILE()
--------------------------------------------------------------------------------
"GENAI"   

--   
-- Use AI
--   
SQL> select ai how many customers exist;
Number of Customers
-------------------
              55500

SQL> select ai how many customers in San Francisco are married;
COUNT(DISTINCTC."CUST_ID")
--------------------------
                        28

SQL> select ai showsql how many customers in San Francisco are married;
RESPONSE                                                                                                                                                                                             
-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SELECT COUNT(DISTINCT c."CUST_ID")
FROM "SH"."CUSTOMERS" c
JOIN "SH"."COUNTRIES" co ON c."COUNTRY_ID" = co."COUNTRY_ID"
WHERE c."CUST_CITY" = 'San Francisco' AND c."CUST_MARITAL_STATUS" = 'married'

SQL> select ai explainsql how many customers in San Francisco are married;
RESPONSE                                                                                                                                                          
Here is the Oracle SQL query to find the number of customers in San Francisco who are married:
```
SELECT COUNT(*)
FROM "SH"."CUSTOMERS" c
WHERE c."CUST_CITY" = 'San Francisco'
AND c."CUST_MARITAL_STATUS" = 'Married';
```
Explanation:
* We use the `COUNT(*)` aggregate function to count the number of rows that match the conditions.
* We specify the table alias `c` for the `"SH"."CUSTOMERS"` table to make the query more readable.
* We use the `WHERE` clause to filter the rows based on two conditions:
    + `c."CUST_CITY" = 'San Francisco'`: We filter the rows where the customer's city is San Francisco.
    + `c."CUST_MARITAL_STATUS" = 'Married'`: We filter the rows where the customer's marital status is Married.
* The double quotes around the table and column names are used to make the query case-sensitive, as required in Oracle SQL.
Note: The column names and table names are assumed to be case-sensitive, so we enclose them in double quotes. If the column names and table names are not case-sensitive, you can remove the double quotes.
Collapse
 This snippet was truncated for display; see it in full

SQL> select ai narrate how many customers in San Francisco are married;

RESPONSE                                                
--------------------------------------------------------
There are 28 customers in San Francisco who are married.


SQL> select ai chat what is Autonomous Database;

RESPONSE                                                                                                                                                                                                                                                                                                    
An Autonomous Database is a type of database that uses artificial intelligence (AI) and machine learning (ML) to automate many of the administrative and maintenance tasks typically performed by a database administrator (DBA). This allows the database to manage itself, without human intervention, to a large extent.
Autonomous databases are designed to be self-driving, self-securing, and self-repairing, which means they can:
1. **Automate administrative tasks**: Such as provisioning, patching, upgrading, and tuning, which frees up DBAs to focus on higher-level tasks.
2. **Optimize performance**: By automatically adjusting parameters, indexing, and caching to ensure optimal performance and efficiency.
3. **Detect and respond to security threats**: By using AI-powered security tools to identify and respond to potential security threats in real-time.
4. **Heal itself**: By automatically detecting and repairing errors, corruption, or other issues that may arise.
5. **Scale up or down**: To match changing workload demands, without the need for manual intervention.
The benefits of Autonomous Databases include:
1. **Increased efficiency**: By automating routine tasks, DBAs can focus on more strategic activities.
2. **Improved performance**: Autonomous databases can optimize performance in real-time, leading to faster query response times and better overall system performance.
3. **Enhanced security**: AI-powered security tools can detect and respond to threats more quickly and effectively than human administrators.
4. **Reduced costs**: By minimizing the need for manual intervention, Autonomous Databases can help reduce labor costs and improve resource utilization.
5. **Improved reliability**: Autonomous Databases can detect and repair errors more quickly, reducing downtime and improving overall system reliability.
Oracle Autonomous Database is a popular example of an Autonomous Database, which was introduced in 2018. Other vendors, such as Amazon, Microsoft, and Google, also offer Autonomous Database services as part of their cloud offerings.
In summary, Autonomous Databases are designed to be self-managing, self-optimizing, and self-healing, which can lead to improved performance, security, and efficiency, while reducing costs and administrative burdens.


--
--Drop the profile
--
EXEC DBMS_CLOUD_AI.DROP_PROFILE('GENAI');
  
PL/SQL procedure successfully completed.
Ejemplo: especificación de una región diferente para el perfil de OCI Generative AI
En este ejemplo se muestra cómo especificar una región soportada de OCI Generative AI en su perfil. Consulte Regiones con IA generativa.
BEGIN                                                                          
	  DBMS_CLOUD_AI.CREATE_PROFILE(                                                
		  profile_name => 'GENAI',
		  attributes   =>'{"provider": "oci",
		    "object_list": [
                        {"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}
                        ]
			"region":"eu-frankfurt-1",
			"model": "meta.llama-3.3-70b-instruct",
            "credential_name": "GENAI_CRED",
            "oci_compartment_id": "ocid1.compartment.oc1..."}');
END;                                                                           
/
Ejemplo: selección de IA con OCI Generative AI mediante el modelo LLAMA

En este ejemplo se muestra la función chat de OCI Generative AI. Destaca las capacidades del modelo a través de dos indicaciones: analizar los comentarios de los clientes para medir su sentimiento y generar un párrafo introductorio sobre la escalada en roca.

BEGIN                                                                          
	  DBMS_CLOUD.CREATE_CREDENTIAL(                                                
		credential_name => 'GENAI_CRED',                                           
		user_ocid       => 'ocid1.user.oc1..aaa',
		tenancy_ocid    => 'ocid1.tenancy.oc1..aaa',
		private_key     => '<your_api_key>',
		fingerprint     => '<your_fingerprint>'       
	  );                                                                           
	 END;                                                                           
	/
	
	PL/SQL procedure successfully completed.
	
BEGIN                                                                          
	  DBMS_CLOUD_AI.CREATE_PROFILE(                                                
		  profile_name => 'GENAI',
		  attributes   =>'{"provider": "oci",
		    "object_list": [
                        {"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}
                        ]
			"model": "meta.llama-3.3-70b-instruct",
			"oci_apiformat":"GENERIC", 
            "credential_name": "GENAI_CRED",
            "oci_compartment_id": "ocid1.compartment.oc1..."}');
	END;                                                                           
	/
	
	PL/SQL procedure successfully completed.

--
--Set profile
--
EXEC DBMS_CLOUD_AI.SET_PROFILE('GENAI');
          
	PL/SQL procedure successfully completed.

SQL> set linesize 150                                                               
SQL> SELECT AI chat what is the sentiment of this comment I am not going to waste my time filling up this three page form. Lousy idea;
SQL>  
	RESPONSE
	------------------------------------------------------------------------------------------------------------------------------------------------------
	
	The sentiment of this comment is strongly negative. The user is expressing frustration and annoyance with the idea of filling out a three-page form, an
       d is explicitly stating that they consider it a "lousy idea". The use of the phrase "waste my time" also implies that they feel the task is unnecessary 
       and unproductive. The tone is dismissive and critical. 
	
SQL> SELECT AI chat Write an enthusiastic introductory paragraph on how to get started with rock climbing with Athletes as the target audience;
	RESPONSE
	------------------------------------------------------------------------------------------------------------------------------------------------------
	Rock climbing is an exhilarating and challenging sport that's perfect for athletes looking to push their limits and test their strength, endurance, 
       and mental toughness. Whether you're a seasoned athlete or just starting out, rock climbing offers a unique and rewarding experience that will have 
       you hooked from the very first climb. With its combination of physical and mental challenges, rock climbing is a great way to build strength, improve
       flexibility, and develop problem-solving skills. Plus, with the supportive community of climbers and the breathtaking views from the top of the climb,
       you'll be hooked from the very first climb. So, if you're ready to take on a new challenge and experience the thrill of adventure, then it's time to 
       get started with rock climbing!
Uso de OCI Generative AI con el modelo por defecto

En el siguiente ejemplo se utiliza el modelo de chat de IA generativa de OCI por defecto. Si no especifica el parámetro model_name, OCI Generative AI utiliza el modelo por defecto según la tabla de Select your AI Provider and LLMs.

BEGIN                                                                        
  DBMS_CLOUD_AI.CREATE_PROFILE(                                              
      profile_name => 'OCI_DEFAULT',
      attributes   => '{"provider": "oci",
                        "credential_name": "OCI_CRED",
                        "object_list": [{"owner": "ADB_USER"}]
                        }');
END;                                                                         
/
Uso de OCI Generative AI con el modelo de chat

En el siguiente ejemplo se utiliza cohere.command-r-plus-08-2024 como modelo de chat de IA generativa de OCI.

BEGIN                                                                        
  DBMS_CLOUD_AI.CREATE_PROFILE(                                              
      profile_name => 'OCI_COHERE_COMMAND_R_PLUS',
      attributes   => '{"provider": "oci",
                        "credential_name": "OCI_CRED",
                        "object_list": [{"owner": "ADB_USER"}],
                        "model": "cohere.command-r-plus-08-2024"
                       }');
END;
/
Uso de OCI Generative AI con ID de punto final de modelo de chat

En el siguiente ejemplo se muestra cómo especificar el ID de punto final del modelo de chat de IA generativa de OCI en lugar de model. Si utiliza el ID de punto final del modelo de chat de Meta Llama, especifique oci_apiformat como GENERIC.

BEGIN                                                                        
  DBMS_CLOUD_AI.CREATE_PROFILE(                                              
      profile_name => 'OCI_CHAT_ENDPOINT',
      attributes => '{"provider": "oci",
                      "credential_name": "OCI_CRED",
                      "object_list": [{"owner": "ADB_USER"}],
                      "oci_endpoint_id": "<endpoint_id>",
                      "oci_apiformat": "GENERIC"
                     }');
END;
/
Uso de OCI Generative AI con el OCID del modelo de chat

En este ejemplo se muestra cómo especificar el ID de punto final del modelo de chat Cohere de IA generativa de OCI en lugar de model. Si utiliza el ID de punto final del modelo de chat de Meta Llama, especifique oci_apiformat como GENERIC.

BEGIN                                                                               
  DBMS_CLOUD_AI.CREATE_PROFILE(
      profile_name => 'OCI_CHAT_OCID',
      attributes   => '{"provider": "oci",
                        "credential_name": "OCI_CRED",
                        "object_list": [{"owner": "ADB_USER"}],
                        "model": "<model_ocid>",
                        "oci_apiformat": "COHERE"
                       }');
END;
/

Ejemplo: seleccione AI con OpenAI

En este ejemplo se muestra cómo puede utilizar OpenAI para generar sentencias SQL a partir de peticiones de datos en lenguaje natural.

Nota

Solo un DBA puede ejecutar los privilegios EXECUTE y el procedimiento de ACL de red.

--Grants EXECUTE privilege to ADB_USER
--
SQL> grant execute on DBMS_CLOUD_AI to ADB_USER;

-- Grant Network ACL for OpenAI endpoint
--
SQL> BEGIN  
     DBMS_NETWORK_ACL_ADMIN.APPEND_HOST_ACE(
         host => 'api.openai.com',
         ace  => xs$ace_type(privilege_list => xs$name_list('http'),
                             principal_name => 'ADB_USER',
                             principal_type => xs_acl.ptype_db)
     );
    END;
    /
 
PL/SQL procedure successfully completed.
 
--
-- Create Credential for AI provider
--
EXEC
DBMS_CLOUD.CREATE_CREDENTIAL(
CREDENTIAL_NAME   => 'OPENAI_CRED', 
username          =>  'OPENAI', 
password          =>  '<your_api_token>');
 
PL/SQL procedure successfully completed.
 
--
-- Create AI profile
--
BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
  profile_name   => 'OPENAI',
  attributes     =>'{"provider": "openai",                                                                   
        "credential_name": "OPENAI_CRED",                                     
        "object_list": [{"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}],
        "conversation": "true"                
       }');                                                                  
END;                                                                         
/ 
 
PL/SQL procedure successfully completed.
 
--
-- Enable AI profile in current session
--
SQL> EXEC DBMS_CLOUD_AI.SET_PROFILE('OPENAI');
 
PL/SQL procedure successfully completed.
 
--
-- Get Profile in current session
--
SQL> SELECT DBMS_CLOUD_AI.get_profile() from dual;
 
DBMS_CLOUD_AI.GET_PROFILE()
--------------------------------------------------------------------------------
"OPENAI"
 
--
-- Use AI
--
SQL> select ai how many customers exist;
 
CUSTOMER_COUNT
--------------
         55500
 
SQL> select ai how many customers in San Francisco are married;   
 
MARRIED_CUSTOMERS
-----------------
               18
 
 
SQL> select ai showsql how many customers in San Francisco are married;
 
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS married_customers_count
FROM SH.CUSTOMERS c
WHERE c.CUST_CITY = 'San Francisco'
  AND c.CUST_MARITAL_STATUS = 'Married'
 

SQL> select ai explainsql how many customers in San Francisco are married;
 
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS customer_count
FROM SH.CUSTOMERS AS c
WHERE c.CUST_STATE_PROVINCE = 'San Francisco' AND c.CUST_MARITAL_STATUS = 'Married';
 
Explanation:
- We use the 'SH' table alias for the 'CUSTOMERS' table for better readability.
- The query uses the 'COUNT(*)' function to count the number of rows that match the given conditions.
- The 'WHERE' clause is used to filter the results:
  - 'c.CUST_STATE_PROVINCE = 'San Francisco'' filters customers who have 'San Francisco' as their state or province.
  - 'c.CUST_MARITAL_STATUS = 'Married'' filters customers who have 'Married' as their marital status.
The result of this query will give you the count of customers in San Francisco who are married, using the column alias 'customer_count' for the result.
 
Remember to adjust the table and column names based on your actual schema if they differ from the example.
 
Feel free to ask if you have more questions related to SQL or database in general.
 
SQL> select ai narrate what are the top 3 customers in San Francisco;
 
RESPONSE
--------------------------------------------------------------------------------
The top 3 customers in San Francisco are:
 
1. Hector Colven - Total amount sold: $52,025.99
2. Milburn Klemm - Total amount sold: $50,842.28
3. Gavin Xie - Total amount sold: $48,677.18
 
 
SQL> select ai chat what is Autonomous Database;
 
RESPONSE
--------------------------------------------------------------------------------
Autonomous Database is a cloud-based database service provided by Oracle. It is designed to automate many of the routine tasks involved in managing a database,
such as patching, tuning, and backups. Autonomous Database uses machine learning and automation to optimize performance, security, and availability, allowing 
users to focus on their applications and data rather than database administration tasks. It offers both Autonomous Transaction Processing (ATP) for 
transactional workloads and Autonomous Data Warehouse (ADW) for analytical workloads. Autonomous Database provides high performance, scalability, and 
reliability, making it an ideal choice for modern cloud-based applications.
 
SQL> EXEC DBMS_CLOUD_AI.DROP_PROFILE('OPENAI');
 
PL/SQL procedure successfully completed.

En el siguiente ejemplo, se muestra la especificación de un modelo diferente en el perfil de AI:

BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
  profile_name   => 'OPENAI',
  attributes     =>'{"provider": "openai",                                                                   
        "credential_name": "OPENAI_CRED",                                     
        "model": "gpt-3.5-turbo",
	 "object_list": [{"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}],
        "conversation": "true"		
       }');                                                                  
END;                                                                         
/ 

Ejemplo: Seleccionar IA con Cohere

En este ejemplo se muestra cómo puede utilizar Cohere para generar sentencias SQL a partir de peticiones de datos de lenguaje natural.

Nota

Solo un DBA puede ejecutar los privilegios EXECUTE y el procedimiento de ACL de red.

--Grants EXECUTE privilege to ADB_USER
--
SQL>GRANT execute on DBMS_CLOUD_AI to ADB_USER;
--
-- Create Credential for AI provider
--
EXEC
DBMS_CLOUD.CREATE_CREDENTIAL(
CREDENTIAL_NAME   => 'COHERE_CRED', 
username          =>  'COHERE', 
password          =>  'your_api_token');
 
PL/SQL procedure successfully completed.
 
--
-- Grant Network ACL for Cohere endpoint
--
SQL> BEGIN  
    DBMS_NETWORK_ACL_ADMIN.APPEND_HOST_ACE(
         host => 'api.cohere.ai',
         ace  => xs$ace_type(privilege_list => xs$name_list('http'),
                             principal_name => 'ADB_USER',
                             principal_type => xs_acl.ptype_db)
    );
     END;
     /
    /
 
PL/SQL procedure successfully completed.
 
--
-- Create AI profile
--
BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
  profile_name   => 'COHERE',
  attributes     =>'{"provider": "cohere",
	 "credential_name": "COHERE_CRED",
        "object_list": [{"owner": "SH", "name": "customers"},
                        {"owner": "SH", "name": "sales"},
                        {"owner": "SH", "name": "products"},
                        {"owner": "SH", "name": "countries"}]
       }');
END;
/
 
PL/SQL procedure successfully completed.
 
--
-- Enable AI profile in current session
--
SQL> EXEC DBMS_CLOUD_AI.SET_PROFILE('COHERE');
 
PL/SQL procedure successfully completed.
 
--
-- Get Profile in current session
--
SQL> SELECT DBMS_CLOUD_AI.get_profile() from dual;
 
DBMS_CLOUD_AI.GET_PROFILE()
--------------------------------------------------------------------------------
"COHERE"
 
--
-- Use AI
--
SQL> select ai how many customers exist;
 
CUSTOMER_COUNT
--------------
         55500
 
SQL> EXEC DBMS_CLOUD_AI.DROP_PROFILE('COHERE');
 
PL/SQL procedure successfully completed.

En el siguiente ejemplo, se muestra cómo especificar un modelo diferente y atributos personalizados en su perfil de AI:


BEGIN
DBMS_CLOUD_AI.CREATE_PROFILE(
     profile_name => 'COHERE',
     attributes =>
      '{"provider": "cohere",
        "credential_name": "COHERE_CRED",
	"model": "cohere.command-a-03-2025",
        "object_list": [{"owner": "ADB_USER"}],
        "max_tokens":512,
        "stop_tokens": [";"],
        "temperature": 0.5,
        "comments": true
       }');
END;
/

Ejemplo: selección de AI con Azure OpenAI Service

En los siguientes ejemplos se muestra cómo puede activar el acceso al servicio OpenAI de Azure mediante la clave de API o utilizar la entidad de servicio OpenAI de Azure, crear un perfil de AI y generar SQL a partir de peticiones de datos de lenguaje natural.

-- Create Credential for AI integration
--
EXEC
DBMS_CLOUD.CREATE_CREDENTIAL(
CREDENTIAL_NAME   => 'AZURE_CRED', 
username          =>  'AZUREAI', 
password          =>  'your_api_token');
  
PL/SQL procedure successfully completed.
  
--
-- Grant Network ACL for OpenAI endpoint
--
BEGIN 
    DBMS_NETWORK_ACL_ADMIN.APPEND_HOST_ACE(
         host => '<azure_resource_name>.openai.azure.com',
         ace  => xs$ace_type(privilege_list => xs$name_list('http'),
                             principal_name => 'ADB_USER',
                             principal_type => xs_acl.ptype_db)
       );
END;
/
  
PL/SQL procedure successfully completed.
  
--
-- Create AI profile
--
BEGIN                                                                         
    DBMS_CLOUD_AI.CREATE_PROFILE(                                               
     profile_name=> 'AZUREAI',                                                              
     attributes=> '{"provider": "azure", 
        "azure_resource_name": "<azure_resource_name>",
        "azure_deployment_name": "<azure_deployment_name>"                                                                     
        "credential_name": "AZURE_CRED",                                      
        "object_list": [{"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}],
        "conversation": "true"                 
       }');                                                                   
END;                                                                          
/
  
PL/SQL procedure successfully completed.
  
--
-- Enable AI profile in current session
--
EXEC DBMS_CLOUD_AI.SET_PROFILE('AZUREAI');
  
PL/SQL procedure successfully completed.

--
-- Get Profile in current session
--
SELECT DBMS_CLOUD_AI.get_profile() from dual;
 
DBMS_CLOUD_AI.GET_PROFILE()
--------------------------------------------------------------------------------
"AZUREAI"
  
  
--
-- Use AI
--
select ai how many customers exist;
  
CUSTOMER_COUNT
--------------
         55500
  
select ai how many customers in San Francisco are married;  
  
MARRIED_CUSTOMERS
-----------------
               18
  
  
select ai showsql how many customers in San Francisco are married;
  
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS married_customers_count
FROM SH.CUSTOMERS c
WHERE c.CUST_CITY = 'San Francisco'
  AND c.CUST_MARITAL_STATUS = 'Married'
  

select ai explainsql how many customers in San Francisco are married;
 
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS customer_count
FROM SH.CUSTOMERS AS c
WHERE c.CUST_STATE_PROVINCE = 'San Francisco' AND c.CUST_MARITAL_STATUS = 'Married';
 
Explanation:
- We use the 'SH' table alias for the 'CUSTOMERS' table for better readability.
- The query uses the 'COUNT(*)' function to count the number of rows that match the given conditions.
- The 'WHERE' clause is used to filter the results:
  - 'c.CUST_STATE_PROVINCE = 'San Francisco'' filters customers who have 'San Francisco' as their state or province.
  - 'c.CUST_MARITAL_STATUS = 'Married'' filters customers who have 'Married' as their marital status.
The result of this query will give you the count of customers in San Francisco who are married, using the column alias 'customer_count' for the result.
 
Remember to adjust the table and column names based on your actual schema if they differ from the example.
 
Feel free to ask if you have more questions related to SQL or database in general.
 
     
select ai narrate what are the top 3 customers in San Francisco;
  
RESPONSE
--------------------------------------------------------------------------------
The top 3 customers in San Francisco are:
  
1. Hector Colven - Total amount sold: $52,025.99
2. Milburn Klemm - Total amount sold: $50,842.28
3. Gavin Xie - Total amount sold: $48,677.18
  
  
select ai chat what is Autonomous Database;
  
RESPONSE
--------------------------------------------------------------------------------
Autonomous Database is a cloud-based database service provided by Oracle. It is designed to automate many of the routine tasks involved in managing a database,
such as patching, tuning, and backups. Autonomous Database uses machine learning and automation to optimize performance, security, and availability, allowing 
users to focus on their applications and data rather than database administration tasks. It offers both Autonomous Transaction Processing (ATP) for transactional
workloads and Autonomous Data Warehouse (ADW) for analytical workloads. Autonomous Database provides high performance, scalability, and reliability, making it 
an ideal choice for modern cloud-based applications.


EXEC DBMS_CLOUD_AI.DROP_PROFILE('AZUREAI');
  
PL/SQL procedure successfully completed.

En el siguiente ejemplo, se muestra la especificación de un modelo diferente en el perfil de AI:

BEGIN                                                                         
    DBMS_CLOUD_AI.CREATE_PROFILE(                                               
      profile_name=>'AZUREAI',                                                              
      attributes=>'{"provider": "azure",                                                  
        "credential_name": "AZURE$PA",
        "model": "gpt-3.5-turbo",                                      
        "object_list": [{"owner": "SH", "name": "customers"},                 
                        {"owner": "SH", "name": "countries"},                 
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                   
                        {"owner": "SH", "name": "promotions"},                
                        {"owner": "SH", "name": "products"}],
	"azure_resource_name": "<azure_resource_name>",                              
        "azure_deployment_name": "<azure_deployment_name>"                  
       }');                                                                   
END;                                                                          
/
Ejemplo: selección de AI con entidad de servicio OpenAI de Azure

Conéctese como administrador de base de datos para proporcionar acceso a la autenticación de entidad de servicio de Azure y, a continuación, otorgue los permisos de ACL de red al usuario (ADB_USER) que desea utilizar Select AI. Para proporcionar acceso a los recursos de Azure, consulte Uso de la entidad de servicio de Azure para acceder a los recursos de Azure.

Nota

Solo un usuario DBA puede ejecutar los privilegios EXECUTE y el procedimiento de ACL de red.
-- Connect as ADMIN user and enable Azure service principal authentication.
BEGIN
  DBMS_CLOUD_ADMIN.ENABLE_PRINCIPAL_AUTH(provider  => 'AZURE',
                                         params    => JSON_OBJECT('azure_tenantid' value 'azure_tenantid'));
END;
/
  
-- Copy the consent url from cloud_integrations view and consents the ADB-S application.
SQL> select param_value from CLOUD_INTEGRATIONS where param_name = 'azure_consent_url';
PARAM_VALUE
--------------------------------------------------------------------------------
https://login.microsoftonline.com/<tenant_id>/oauth2/v2.0/authorize?client_id=<client_id>&response_type=code&scope=User.read
  
-- On the Azure OpenAI IAM console, search for the Azure application name and assign the permission to the application.
-- You can get the application name in the cloud_integrations view.
SQL> select param_value from CLOUD_INTEGRATIONS where param_name = 'azure_app_name';
PARAM_VALUE
--------------------------------------------------------------------------------
ADBS_APP_DATABASE_OCID
  
--
-- Grant Network ACL for Azure OpenAI endpoint
--SQL> BEGIN 
    DBMS_NETWORK_ACL_ADMIN.APPEND_HOST_ACE(
         host => 'azure_resource_name.openai.azure.com',
         ace  => xs$ace_type(privilege_list => xs$name_list('http'),
                             principal_name => 'ADB_USER',
                             principal_type => xs_acl.ptype_db)
       );
       END;
       /
  
PL/SQL procedure successfully completed.
  
--
-- Create AI profile
--
BEGIN                                                                         
    DBMS_CLOUD_AI.CREATE_PROFILE(                                               
      profile_name=>'AZUREAI',                                                              
      attributes=>'{"provider": "azure",                                                  
        "credential_name": "AZURE$PA",                                      
        "object_list": [{"owner": "SH", "name": "customers"},                 
                        {"owner": "SH", "name": "countries"},                 
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                   
                        {"owner": "SH", "name": "promotions"},                
                        {"owner": "SH", "name": "products"}],                 
        "azure_resource_name": "<azure_resource_name>",                              
        "azure_deployment_name": "<azure_deployment_name>"                  
       }');                                                                   
END;                                                                          
/
  
PL/SQL procedure successfully completed.
  
--
-- Enable AI profile in current session
--
EXEC DBMS_CLOUD_AI.SET_PROFILE('AZUREAI');
  
PL/SQL procedure successfully completed.
  
--
-- Get Profile in current session
--
SELECT DBMS_CLOUD_AI.get_profile() from dual;
 
DBMS_CLOUD_AI.GET_PROFILE()
--------------------------------------------------------------------------------
"AZUREAI"  

--
-- Use AI
--
select ai how many customers exist;
  
CUSTOMER_COUNT
--------------
         55500
  
select ai how many customers in San Francisco are married;  
  
MARRIED_CUSTOMERS
-----------------
               18
  
 
select ai showsql how many customers in San Francisco are married;
  
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS married_customers_count
FROM SH.CUSTOMERS c
WHERE c.CUST_CITY = 'San Francisco'
  AND c.CUST_MARITAL_STATUS = 'Married'
  

select ai explainsql how many customers in San Francisco are married;
 
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS customer_count
FROM SH.CUSTOMERS AS c
WHERE c.CUST_STATE_PROVINCE = 'San Francisco' AND c.CUST_MARITAL_STATUS = 'Married';
 
Explanation:
- We use the 'SH' table alias for the 'CUSTOMERS' table for better readability.
- The query uses the 'COUNT(*)' function to count the number of rows that match the given conditions.
- The 'WHERE' clause is used to filter the results:
  - 'c.CUST_STATE_PROVINCE = 'San Francisco'' filters customers who have 'San Francisco' as their state or province.
  - 'c.CUST_MARITAL_STATUS = 'Married'' filters customers who have 'Married' as their marital status.
The result of this query will give you the count of customers in San Francisco who are married, using the column alias 'customer_count' for the result.
 
Remember to adjust the table and column names based on your actual schema if they differ from the example.
 
Feel free to ask if you have more questions related to SQL or database in general.
  
select ai narrate what are the top 3 customers in San Francisco;
  
RESPONSE
--------------------------------------------------------------------------------
The top 3 customers in San Francisco are:
  
1. Hector Colven - Total amount sold: $52,025.99
2. Milburn Klemm - Total amount sold: $50,842.28
3. Gavin Xie - Total amount sold: $48,677.18
  
  
select ai chat what is Autonomous Database;
  
RESPONSE
--------------------------------------------------------------------------------
Autonomous Database is a cloud-based database service provided by Oracle. It is designed to automate many of the routine tasks involved in managing a database,
such as patching, tuning, and backups. Autonomous Database uses machine learning and automation to optimize performance, security, and availability, allowing us
ers to focus on their applications and data rather than database administration tasks. It offers both Autonomous Transaction Processing (ATP) for transactional
workloads and Autonomous Data Warehouse (ADW) for analytical workloads. Autonomous Database provides high performance, scalability, and reliability, making it 
an ideal choice for modern cloud-based applications.
 
EXEC DBMS_CLOUD_AI.DROP_PROFILE('AZUREAI');
  
PL/SQL procedure successfully completed.

Ejemplo: Seleccionar AI con Google

En este ejemplo, se muestra cómo puede utilizar Google para generar, ejecutar y explicar SQL a partir de peticiones de datos en lenguaje natural o chatear mediante el LLM de Google Gemini.

En el siguiente ejemplo, se muestra el uso de Google como proveedor de IA. En el ejemplo se muestra el uso de la clave de firma de la API de Google para proporcionar acceso a la red, crear un perfil de IA y utilizar las acciones Seleccionar IA para generar consultas SQL a partir de peticiones de datos en lenguaje natural y respuestas de chat.

--Grants EXECUTE privilege to ADB_USER
--
SQL> grant EXECUTE on DBMS_CLOUD_AI to ADB_USER; 

--
-- Create Credential for AI provider
--
SQL> BEGIN
      DBMS_CLOUD.CREATE_CREDENTIAL(
        credential_name => 'GOOGLE_CRED',
        username    => 'GOOGLE',
        password    => '<your_api_key>'
      );
     END;
    /
 
PL/SQL procedure successfully completed.

--
-- Grant Network ACL for Google endpoint
--
SQL>
SQL> BEGIN
      DBMS_NETWORK_ACL_ADB_USER.APPEND_HOST_ACE(
        host => 'generativelanguage.googleapis.com',
        ace  => xs$ace_type(privilege_list => xs$name_list('http'),
                    principal_name => 'ADB_USER',
                    principal_type => xs_acl.ptype_db)
       );
     END;
    /
 
PL/SQL procedure successfully completed.

--
-- Create AI profile 
--
SQL> BEGIN
      DBMS_CLOUD_AI.CREATE_PROFILE(
        profile_name =>'GOOGLE',
        attributes   =>'{"provider": "google",
          "credential_name": "GOOGLE_CRED",
          "object_list": [{"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}]
         }');
     END;
   /
 
PL/SQL procedure successfully completed.

--
-- Enable AI profile in current session
--
SQL> EXEC DBMS_CLOUD_AI.SET_PROFILE('GOOGLE');
 
PL/SQL procedure successfully completed.
 
--
-- Use AI
--   
SQL> select ai how many customers exist;
 
CUSTOMER_COUNT
--------------
         55500
 
SQL> select ai how many customers in San Francisco are married;   
 
MARRIED_CUSTOMERS
-----------------
               18
 
 
SQL> select ai showsql how many customers in San Francisco are married;
 
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS married_customers_count
FROM SH.CUSTOMERS c
WHERE c.CUST_CITY = 'San Francisco'
  AND c.CUST_MARITAL_STATUS = 'Married'
 

SQL> select ai explainsql how many customers in San Francisco are married;
 
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS customer_count
FROM SH.CUSTOMERS AS c
WHERE c.CUST_STATE_PROVINCE = 'San Francisco' AND c.CUST_MARITAL_STATUS = 'Married';
 
Explanation:
- We use the 'SH' table alias for the 'CUSTOMERS' table for better readability.
- The query uses the 'COUNT(*)' function to count the number of rows that match the given conditions.
- The 'WHERE' clause is used to filter the results:
  - 'c.CUST_STATE_PROVINCE = 'San Francisco'' filters customers who have 'San Francisco' as their state or province.
  - 'c.CUST_MARITAL_STATUS = 'Married'' filters customers who have 'Married' as their marital status.
The result of this query will give you the count of customers in San Francisco who are married, using the column alias 'customer_count' for the result.
 
Remember to adjust the table and column names based on your actual schema if they differ from the example.
 
Feel free to ask if you have more questions related to SQL or database in general.    
 
SQL> select ai narrate what are the top 3 customers in San Francisco;
 
RESPONSE
--------------------------------------------------------------------------------
The top 3 customers in San Francisco are:
 
1. Hector Colven - Total amount sold: $52,025.99
2. Milburn Klemm - Total amount sold: $50,842.28
3. Gavin Xie - Total amount sold: $48,677.18
 
 
SQL> select ai chat what is Autonomous Database;
 
RESPONSE
--------------------------------------------------------------------------------
Autonomous Database is a cloud-based database service provided by Oracle. It is designed to automate many of the routine tasks involved in managing a database,
such as patching, tuning, and backups. Autonomous Database uses machine learning and automation to optimize performance, security, and availability, allowing 
users to focus on their applications and data rather than database administration tasks. It offers both Autonomous Transaction Processing (ATP) for transactional
workloads and Autonomous Data Warehouse (ADW) for analytical workloads. Autonomous Database provides high performance, scalability, and reliability, making it 
an ideal choice for modern cloud-based applications.

--
--Drop the profile
--
EXEC DBMS_CLOUD_AI.DROP_PROFILE('GOOGLE');
  
PL/SQL procedure successfully completed.                                                                           

En el siguiente ejemplo, se muestra la especificación de un modelo diferente en el perfil de AI:

BEGIN
      DBMS_CLOUD_AI.CREATE_PROFILE(
        profile_name =>'GOOGLE',
        attributes   =>'{"provider": "google",
          "credential_name": "GOOGLE_CRED",
          "model": "gemini-1.5-pro",
          "object_list": [{"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}]
			         }');
END;
/

Ejemplo: selección de IA con antrópico

En este ejemplo se muestra cómo puede utilizar Anthropic para generar, ejecutar y explicar SQL a partir de peticiones de datos de lenguaje natural o chat mediante Anthropic Claude LLM.

En el siguiente ejemplo, se muestra el uso de Anthropic como proveedor de AI. En el ejemplo, se muestra el uso de la clave de firma de la API antrópica para proporcionar acceso a la red, crear un perfil de IA y utilizar acciones Select AI para generar consultas SQL a partir de peticiones de datos en lenguaje natural y chatear mediante el LLM de Anthropic Claude.

Consulte Atributos de perfil para proporcionar los atributos de perfil.

--Grant EXECUTE privilege to ADB_USER

SQL>GRANT EXECUTE on DBMS_CLOUD_AI to ADB_USER; 

--
-- Create Credential for AI provider
--

SQL>BEGIN
      DBMS_CLOUD.CREATE_CREDENTIAL(
        credential_name => 'ANTHROPIC_CRED',
        username    => 'ANTHROPIC',
        password    => '<your api key>'
      );
    END;
     /
 
PL/SQL procedure successfully completed.
 

--
-- Grant Network ACL for Anthropic endpoint
--
SQL>BEGIN
      DBMS_NETWORK_ACL_ADB_USER.APPEND_HOST_ACE(
        host => 'api.anthropic.com',
        ace  => xs$ace_type(privilege_list => xs$name_list('http'),
                    principal_name => 'ADB_USER',
                    principal_type => xs_acl.ptype_db)
       );
     END;
    /
 
PL/SQL procedure successfully completed.
 
--
-- Create AI profile 
--
SQL>BEGIN
      DBMS_CLOUD_AI.CREATE_PROFILE(
        profile_name =>'ANTHROPIC',
        attributes   =>'{"provider": "anthropic",
          "credential_name": "ANTHROPIC_CRED",
          "object_list": [{"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}]
         }');
    END;
     /
 
PL/SQL procedure successfully completed.
 
--
-- Enable AI profile in current session
--
SQL>EXEC DBMS_CLOUD_AI.SET_PROFILE('ANTHROPIC');
 
PL/SQL procedure successfully completed.
 
--
-- Use AI
--
SQL> select ai how many customers exist;
 
CUSTOMER_COUNT
--------------
         55500
 
SQL> select ai how many customers in San Francisco are married;   
 
MARRIED_CUSTOMERS
-----------------
               18
 
 
SQL> select ai showsql how many customers in San Francisco are married;
 
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS married_customers_count
FROM SH.CUSTOMERS c
WHERE c.CUST_CITY = 'San Francisco'
  AND c.CUST_MARITAL_STATUS = 'Married'
 

SQL> select ai explainsql how many customers in San Francisco are married;
 
RESPONSE
--------------------------------------------------------------------------------
SELECT COUNT(*) AS customer_count
FROM SH.CUSTOMERS AS c
WHERE c.CUST_STATE_PROVINCE = 'San Francisco' AND c.CUST_MARITAL_STATUS = 'Married';
 
Explanation:
- We use the 'SH' table alias for the 'CUSTOMERS' table for better readability.
- The query uses the 'COUNT(*)' function to count the number of rows that match the given conditions.
- The 'WHERE' clause is used to filter the results:
  - 'c.CUST_STATE_PROVINCE = 'San Francisco'' filters customers who have 'San Francisco' as their state or province.
  - 'c.CUST_MARITAL_STATUS = 'Married'' filters customers who have 'Married' as their marital status.
The result of this query will give you the count of customers in San Francisco who are married, using the column alias 'customer_count' for the result.
 
Remember to adjust the table and column names based on your actual schema if they differ from the example.
 
Feel free to ask if you have more questions related to SQL or database in general.
 
SQL> select ai narrate what are the top 3 customers in San Francisco;
 
RESPONSE
--------------------------------------------------------------------------------
The top 3 customers in San Francisco are:
 
1. Hector Colven - Total amount sold: $52,025.99
2. Milburn Klemm - Total amount sold: $50,842.28
3. Gavin Xie - Total amount sold: $48,677.18
 
 
SQL> select ai chat what is Autonomous Database;
 
RESPONSE
--------------------------------------------------------------------------------
Autonomous Database is a cloud-based database service provided by Oracle. It is designed to automate many of the routine tasks involved in managing a database,
such as patching, tuning, and backups. Autonomous Database uses machine learning and automation to optimize performance, security, and availability, allowing 
users to focus on their applications and data rather than database administration tasks. It offers both Autonomous Transaction Processing (ATP) for transactional
workloads and Autonomous Data Warehouse (ADW) for analytical workloads. Autonomous Database provides high performance, scalability, and reliability, making it 
an ideal choice for modern cloud-based applications.


--
--Drop the profile
--
EXEC DBMS_CLOUD_AI.DROP_PROFILE('ANTHROPIC');
  
PL/SQL procedure successfully completed.

En el siguiente ejemplo, se muestra la especificación de un modelo diferente en el perfil de AI:

BEGIN
      DBMS_CLOUD_AI.CREATE_PROFILE(
        profile_name =>'ANTHROPIC',
        attributes   =>'{"provider": "anthropic",
          "credential_name": "ANTHROPIC_CRED",
          "model": "claude-3-opus-20240229",
          "object_list": [{"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}]			    
         }');
END;
/

Ejemplo: Seleccionar IA con cara de abrazo

En este ejemplo se muestra cómo puede utilizar Hugging Face para generar, ejecutar y explicar SQL a partir de peticiones de datos en lenguaje natural o chatear mediante el LLM de Hugging Face.

En el siguiente ejemplo, se muestra el uso de Hugging Face como proveedor de IA. En el ejemplo, se muestra el uso de la clave de firma de la API Hugging Face para proporcionar acceso a la red, crear un perfil de IA y utilizar acciones Select AI para generar consultas SQL a partir de peticiones de datos en lenguaje natural y chatear mediante el LLM Hugging Face.

--Grant EXECUTE privilege to ADB_USER

SQL>GRANT EXECUTE on DBMS_CLOUD_AI to ADB_USER; 

--
-- Create Credential for AI provider
--
SQL>BEGIN
      DBMS_CLOUD.CREATE_CREDENTIAL(
        credential_name => 'HF_CRED',
        username    => 'HF',
        password    => '<your_api_key>'
      );
    END;
     /
 
PL/SQL procedure successfully completed.
 
--
-- Grant Network ACL for Hugging Face endpoint
--
SQL>BEGIN
      DBMS_NETWORK_ACL_ADMIN.APPEND_HOST_ACE(
        host => 'api-inference.huggingface.co',
        ace  => xs$ace_type(privilege_list => xs$name_list('http'),
                    principal_name => 'ADB_USER',
                    principal_type => xs_acl.ptype_db)
       );
    END;
     /
 
PL/SQL procedure successfully completed.
 


--
-- Create AI profile 
--
SQL>BEGIN
      DBMS_CLOUD_AI.CREATE_PROFILE(
        profile_name =>'HF',
        attributes   =>'{"provider": "huggingface",
          "credential_name": "HF_CRED",
          "object_list": [{"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}],
           "model" : "Qwen/Qwen2.5-72B-Instruct"
         }');
    END;
     /
 
 
PL/SQL procedure successfully completed.


--
-- Enable AI profile in current session
--
SQL>EXEC DBMS_CLOUD_AI.SET_PROFILE('HF');

PL/SQL procedure successfully completed.
 
--
-- Use AI
--SQL> select ai how many customers exist;

Customer_Count
--------------
         55500

SQL> select ai how many customers in San Francisco are married;

Married_Customers
-----------------
               46

SQL> select ai showsql how many customers in San Francisco are married;

RESPONSE                                                    
------------------------------------------------------------
SELECT COUNT("CUST_ID") AS "Married_Customers"
FROM "SH"."CUSTOMERS" "C"
WHERE "CUST_CITY" = 'San Francisco' AND "CUST_MARITAL_STATUS
" = 'Married'

SQL> select ai explainsql how many customers in San Francisco are married;

RESPONSE                                                    
------------------------------------------------------------
To answer the question "How many customers in San Francisco are married?", we need to query the "SH"."CUSTOMERS" table and filter the results based on the city and marital status. 
We will use table aliases to make the query more readable and ensure that the string comparisons follow the specified rules.

Here is the Oracle SQL query:

```sql
SELECT COUNT("CUST_ID") AS "Married_Customers_in_San_Francisco"
FROM "SH"."CUSTOMERS" c
WHERE c."CUST_CITY" = 'San Francisco' -- Case insensitive comparison
  AND UPPER(c."CUST_MARITAL_STATUS") = UPPER('Married'); -- 
Case insensitive comparison
```

### Explanation:

1. **Table Alias**:

RESPONSE                                                    
------------------------------------------------------------
   - We use the alias `c` for the "SH"."CUSTOMERS" table to make the query more readable.

2. **Column Selection**:
   - We select the count of "CUST_ID" to get the number of customers who meet the criteria. We alias this count as "Married_Customers_in_San_Francisco" for clarity.

3. **WHERE Clause**:
   - **City Filter**: `c."CUST_CITY" = 'San Francisco'`
     - Since 'San Francisco' is not in double quotes, we use a case-insensitive comparison.
   - **Marital Status Filter**: `UPPER(c."CUST_MARITAL_STATUS") = UPPER('Married')`
     - Since 'Married' is not in double quotes, we use a case-insensitive comparison by applying the `UPPER` function to both sides of the comparison.

This query will return the number of customers in San Francisco who are married.



SQL> select ai narrate what are the top 3 customers in San Francisco;

RESPONSE                                                    
------------------------------------------------------------
The top 3 customers in San Francisco are:

- Hector Colven, with a customer ID of 8866.
- Milburn Klemm, with a customer ID of 1944.
- Gavin Xie, with a customer ID of 2579.

These customers have the highest total sales among all customers in San Francisco.


SQL> select ai chat what is Autonomous Database;

RESPONSE                                                    
------------------------------------------------------------
An Autonomous Database is a type of database management system that uses artificial intelligence (AI) and machine learning (ML) to automate many of the routine tasks typically performed by database administrators (DBAs). These tasks include provisioning, patching, backups, tuning, and security. The goal of an autonomous database is to reduce the need for human intervention, minimize errors, and optimize performance,thereby allowing organizations to focus on more strategic activities.

### Key Features of Autonomous Databases:

RESPONSE                                                    
------------------------------------------------------------
1. **Automated Provisioning**: The database can be set up and configured automatically, reducing the time and effort required to get it up and running.
2. **Self-Patching and Updates**: The database automatically applies security patches and updates without downtime, ensuring that the system remains secure and up-to-date.
3. **Self-Tuning**: The database continuously monitors its performance and adjusts settings to optimize query execution and resource utilization.
4. **Self-Backup and Recovery**: Automated backup and recovery processes ensure that data is protected and can be restored quickly in the event of a failure.
5. **Security**: Advanced security features, including threat detection and response, are built into the database to protect against cyber threats.
6. **Scalability**: The database can automatically scale resources up or down based on demand, ensuring optimal performance and cost efficiency.
7. **Monitoring and Diagnostics**: Real-time monitoring and diagnostics help identify and resolve issues before they impact performance.


RESPONSE                                                    
------------------------------------------------------------
### Benefits of Autonomous Databases:
- **Reduced Operational Costs**: By automating routine tasks, the need for dedicated DBAs is reduced, lowering operational costs.
- **Improved Reliability**: Automated processes reduce the risk of human error, leading to more reliable and consistent performance.
- **Enhanced Security**: Continuous monitoring and automated security measures help protect against threats.
- **Faster Time to Market**: Automated provisioning and tuning allow applications to be deployed more quickly.

RESPONSE                                                    
------------------------------------------------------------
- **Scalability and Flexibility**: The ability to scale resources automatically ensures that the database can handle varying workloads efficiently.

### Use Cases:
- **Cloud Applications**: Autonomous databases are particularly useful in cloud environments where scalability and reliability are critical.
- **Data Warehousing**: They can handle large volumes of data and complex queries, making them ideal for data warehousing and analytics.

RESPONSE                                                    
------------------------------------------------------------
- **IoT and Real-Time Data Processing**: They can process and analyze real-time data from IoT devices efficiently.
- **E-commerce**: They can handle high transaction volumes and ensure fast response times for online shopping platforms.


### Examples of Autonomous Databases:
- **Oracle Autonomous Database**: One of the first and most well-known autonomous databases, offering both transactional
 and data warehousing capabilities.
- **Amazon Aurora**: A managed relational database service that includes automated scaling, patching, and backups.
- **Microsoft Azure SQL Database Managed Instance**: Provides a high level of automation and management for SQL Server databases in the cloud.
- **Google Cloud Spanner**: A globally distributed, horizontally scalable relational database that is highly available and consistent.

Autonomous databases represent a significant advancement in database technology, offering organizations a more efficient, secure, and cost-effective way to manage their data.

SQL> EXEC DBMS_CLOUD_AI.DROP_PROFILE('HF');
 
PL/SQL procedure successfully completed.

Ejemplo: activación de conversaciones en Select AI

En este ejemplo, se muestra la activación de conversaciones en Select AI.

Nota

Solo un DBA puede ejecutar los privilegios EXECUTE y el procedimiento de ACL de red.

Cree su perfil de IA. Defina el atributo conversation en true en el perfil, esta acción incluye contenido de interacciones o peticiones de datos anteriores, que pueden incluir metadatos de esquema, y defina el perfil. Una vez habilitado el perfil, puede comenzar a tener conversaciones con sus datos. Utiliza el lenguaje natural para hacer preguntas y hacer un seguimiento según sea necesario.


--Grants EXECUTE privilege to ADB_USER
--
SQL> grant execute on DBMS_CLOUD_AI to ADB_USER;

-- Grant Network ACL for OpenAI endpoint
--
SQL> BEGIN  
     DBMS_NETWORK_ACL_ADMIN.APPEND_HOST_ACE(
         host => 'api.openai.com',
         ace  => xs$ace_type(privilege_list => xs$name_list('http'),
                             principal_name => 'ADB_USER',
                             principal_type => xs_acl.ptype_db)
     );
    END;
    /
 
PL/SQL procedure successfully completed.
 
--
-- Create Credential for AI provider
--
EXEC
DBMS_CLOUD.CREATE_CREDENTIAL(
CREDENTIAL_NAME   => 'OPENAI_CRED', 
username          =>  'OPENAI', 
password          =>  '<your_api_token>');
 
PL/SQL procedure successfully completed.
 
--
-- Create AI profile
--
BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
  profile_name   => 'OPENAI',
  attributes     =>'{"provider": "openai",                                                                   
        "credential_name": "OPENAI_CRED",                                     
        "object_list": [{"owner": "SH", "name": "customers"},                
                        {"owner": "SH", "name": "countries"},                
                        {"owner": "SH", "name": "supplementary_demographics"},
                        {"owner": "SH", "name": "profits"},                  
                        {"owner": "SH", "name": "promotions"},               
                        {"owner": "SH", "name": "products"}],
        "conversation": "true"                
       }');                                                                  
     END;                                                                         
     / 
 
PL/SQL procedure successfully completed.
 
--
-- Enable AI profile in current session
--
SQL> EXEC DBMS_CLOUD_AI.SET_PROFILE('OPENAI');
 
PL/SQL procedure successfully completed.
 
--
-- Get Profile in current session
--
SQL> SELECT DBMS_CLOUD_AI.get_profile() from dual;
 
DBMS_CLOUD_AI.GET_PROFILE()
--------------------------------------------------------------------------------
"OPENAI"
 
--
-- Use AI
--
what are the total number of customers;
 
CUSTOMER_COUNT
--------------
         55500
 
break out count of customers by country;   
 
RESPONSE
-----------------
COUNTRY_NAME 			CUSTOMER_COUNT
Italy 				7780
Brazil 				832
Japan 				624
United Kingdom 			7557
Germany 			8173
United States of America 	18520
France 				3833
Canada 				2010
Spain 				2039
China 				712
Singapore 			597
New Zealand 			244
Poland 	708
Australia 			831
Argentina 			403
Denmark 			383
South Africa 			88
Saudi Arabia 			75
Turkey 				91

  
what age group is most common;
 
RESPONSE
--------------------------------------------------------------------------------
AGE_GROUP 	CUSTOMER_COUNT
65+ 		28226
 
select ai keep the top 5 customers and their country by their purchases and include a rank in the result;
 
RESPONSE
--------------------------------------------------------------------------------
RANK 	CUSTOMER_NAME 		COUNTRY 	PURCHASES
1 	Abigail Ruddy 		Japan 		276
2 	Abigail Ruddy 		Italy 		168
3 	Abigail Ruddy 		Japan 		74
3 	Abner Robbinette 	Germany 	74
5 	Abner Everett 		France 		68
 
 
SQL> EXEC DBMS_CLOUD_AI.DROP_PROFILE('OPENAI');
 
PL/SQL procedure successfully completed.

Ejemplo: configuración y uso de Select AI con RAG

En este ejemplo, se le guía a través de la configuración de credenciales, la configuración del acceso a la red y la creación de un índice vectorial para integrar los servicios en la nube del almacén de vectores de OCI Generative AI con OpenAI mediante Oracle Autonomous Database.

La configuración concluye con la creación de un perfil de IA que utiliza el índice vectorial para mejorar las respuestas de LLM. Por último, en este ejemplo se utiliza la acción Select AI narrate, que devuelve una respuesta que se ha mejorado mediante la información de la base de datos de vectores especificada.

En el siguiente ejemplo se muestra la creación y consulta del índice vectorial en Oracle 23ai.

--Grants EXECUTE privilege to ADB_USER
GRANT EXECUTE on DBMS_CLOUD_AI to ADB_USER; 

--Grants EXECUTE privilege DBMS_CLOUD_PIPELINE to ADB_USER
GRANT EXECUTE on DBMS_CLOUD_PIPELINE to ADB_USER;

-- Create the OpenAI credential
BEGIN
      DBMS_CLOUD.CREATE_CREDENTIAL(
        credential_name => 'OPENAI_CRED',
        username => 'OPENAI_CRED',
        password => '<your_api_key>'
      );
END;
/

PL/SQL procedure successfully completed.

 -- Append the OpenAI endpoint
BEGIN
        DBMS_NETWORK_ACL_ADMIN.APPEND_HOST_ACE(
             host => 'api.openai.com',
             ace  => xs$ace_type(privilege_list => xs$name_list('http'),
                     principal_name => 'ADB_USER',
                     principal_type => xs_acl.ptype_db)
       );
END;
/

PL/SQL procedure successfully completed.

 
-- Create the object store credential
BEGIN
      DBMS_CLOUD.CREATE_CREDENTIAL(
        credential_name => 'OCI_CRED',
        username => '<your_username>',
        password => '<OCI_profile_password>'
      );
END;
/

PL/SQL procedure successfully completed.

 -- Create the profile with the vector index.

BEGIN
      DBMS_CLOUD_AI.CREATE_PROFILE(
          profile_name =>'OPENAI_ORACLE',
          attributes   =>'{"provider": "openai",
            "credential_name": "OPENAI_CRED",
            "vector_index_name": "MY_INDEX",
            "temperature": 0.2,
            "max_tokens": 4096,
            "model": "gpt-3.5-turbo-1106"
          }');
END;
/

PL/SQL procedure successfully completed.

-- Set profile
EXEC DBMS_CLOUD_AI.SET_PROFILE('OPENAI_ORACLE');

PL/SQL procedure successfully completed.                                            
 
-- create a vector index with the vector store name, object store location and
-- object store credential
BEGIN
       DBMS_CLOUD_AI.CREATE_VECTOR_INDEX(
         index_name  => 'MY_INDEX',
         attributes  => '{"vector_db_provider": "oracle",
                          "location": "https://swiftobjectstorage.us-phoenix-1.oraclecloud.com/v1/my_namespace/my_bucket/my_data_folder",
                          "object_storage_credential_name": "OCI_CRED",
                          "profile_name": "OPENAI_ORACLE",
                          "vector_dimension": 1536,
                          "vector_distance_metric": "cosine",
                          "chunk_overlap":128,
                          "chunk_size":1024
      }');
END;
/
PL/SQL procedure successfully completed.  
                                                                                
-- After the vector index is populated, we can now query the index.




-- Set profile
EXEC DBMS_CLOUD_AI.SET_PROFILE('OPENAI_ORACLE');

PL/SQL procedure successfully completed.

-- Select AI answers the question with the knowledge available in the vector database.

set pages 1000
set linesize 150
SELECT AI narrate how can I deploy an oracle machine learning model;
RESPONSE                                                  
To deploy an Oracle Machine Learning model, you would first build your model within the Oracle database. Once your in-database models are built, they become immediately available for use, for instance, through a SQL query using the prediction operators built into the SQL language. 

The model scoring, like model building, occurs directly in the database, eliminating the need for a separate engine or environment within which the model and corresponding algorithm code operate. You can also use models from a different schema (user account) if the appropriate permissions are in place.

Sources:
  - Manage-your-models-with-Oracle-Machine-Learning-on-Autonomous-Database.txt (https://objectstorage.../v1/my_namespace/my_bucket/my_data_folder/Manage-your-models-with-Oracle-Machine-Learning-on-Autonomous-Database.txt)
  - Develop-and-deploy-machine-learning-models-using-Oracle-Autonomous-Database-Machine-Learning-and-APEX.txt (https://objectstorage.../v1/my_namespace/my_bucket/my_data_folder/Develop-and-deploy-machine-learning-models-using-Oracle-Autonomous-Database-Machine-Learning-and-APEX.txt)

Ejemplo: selección de IA con modelos de transformador en la base de datos

En este ejemplo se muestra cómo importar un modelo de transformador previamente entrenado que se almacena en el almacenamiento de objetos de Oracle en la instancia de Oracle Database 23ai y, a continuación, utilizar el modelo importado en la base de datos en el perfil Select AI para generar incrustaciones de vectores para fragmentos de documentos y peticiones de datos de usuario.

Para utilizar modelos de transformadores en la base de datos en su perfil Select AI, asegúrese de tener:
  • el modelo previamente entrenado importado en la instancia de Oracle Database 23ai.

  • opcionalmente, acceda al almacenamiento de objetos de Oracle.

Importación de un modelo de transformador previamente entrenado a Oracle Database 23ai desde Oracle Object Storage

Revise los pasos de Importación de modelos entrenados previamente en formato ONNX para la generación de vectores en la base de datos y el blog Modelo de generación de embebido incorporado previamente para Oracle Database 23ai para importar un modelo de transformador entrenado previamente en la base de datos.

En el siguiente ejemplo se muestra cómo importar un modelo de transformador mantenido desde el almacenamiento de objetos de Oracle a la base de datos y, a continuación, ver el modelo importado.

- Create a Directory object, or use an existing directory object
CREATE OR REPLACE DIRECTORY ONNX_DIR AS 'onnx_model';
 
-- Object storage bucket
VAR location_uri VARCHAR2(4000);
EXEC :location_uri := 'https://adwc4pm.objectstorage.us-ashburn-1.oci.customer-oci.com/p/eLddQappgBJ7jNi6Guz9m9LOtYe2u8LWY19GfgU8flFK4N9YgP4kTlrE9Px3pE12/n/adwc4pm/b/OML-Resources/o/';
 
-- Model file name
VAR file_name VARCHAR2(512);
EXEC :file_name := 'all_MiniLM_L12_v2.onnx';
 
-- Download ONNX model from object storage into the directory object
BEGIN
  DBMS_CLOUD.GET_OBJECT(                           
        credential_name => NULL,
        directory_name  => 'ONNX_DIR',
        object_uri      => :location_uri || :file_name);
END;
/
 
-- Load the ONNX model into the database
BEGIN
  DBMS_VECTOR.LOAD_ONNX_MODEL(
        directory  => 'ONNX_DIR',
        file_name  => :file_name,
        model_name => 'MY_ONNX_MODEL');
END;
/
 
-- Verify
SELECT model_name, algorithm, mining_function
FROM user_mining_models
WHERE  model_name='MY_ONNX_MODEL';
Uso de modelos de transformadores en la base de datos en perfiles de IA seleccionados

Estos ejemplos ilustran cómo utilizar modelos de transformadores en la base de datos dentro de un perfil Select AI. Un perfil se configura solo para generar incrustaciones de vectores, mientras que el otro admite tanto las acciones Select AI como la creación de índices vectoriales.

Revise Examples of Privileges to Run Select AI para completar los requisitos.

A continuación se muestra un ejemplo para generar incrustaciones de vectores únicamente:

BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
     profile_name => 'EMBEDDING_PROFILE',
     attributes   => '{"provider" : "database",
                       "embedding_model": "MY_ONNX_MODEL"}'
  );
END;
/

A continuación se muestra un ejemplo de acciones generales de selección de IA y generación de índices vectoriales donde puede especificar un proveedor de IA soportado. En este ejemplo se utilizan el perfil y las credenciales de OCI Gen AI. Consulte Seleccionar su proveedor de IA y LLM para obtener una lista de proveedores admitidos. Sin embargo, si desea utilizar un modelo de transformador en la base de datos para generar incrustaciones de vectores, utilice "database: <MY_ONNX_MODEL>" en el atributo embedding_model:

BEGIN                                                                        
  DBMS_CLOUD.CREATE_CREDENTIAL(                                              
    credential_name => 'GENAI_CRED',                                         
    user_ocid       => 'ocid1.user.oc1..aaaa...',
    tenancy_ocid    => 'ocid1.tenancy.oc1..aaaa...',
    private_key     => '<your_api_key>',
    fingerprint     => '<your_fingerprint>'     
  );                                                                         
END;                                                                        
/

BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
     profile_name => 'OCI_GENAI',
     attributes   => '{"provider": "oci",
                       "model": "meta.llama-3.3-70b-instruct",
                       "credential_name": "GENAI_CRED",
                       "vector_index_name": "MY_INDEX",
                       "embedding_model": "database: MY_ONNX_MODEL"}'
  );
END;
/
Uso de Select AI con un modelo de transformador en la base de datos de otro esquema

En este ejemplo se muestra cómo utilizar Select AI con un modelo de transformador en la base de datos si otro propietario de esquema es propietario del modelo. Especifique schema_name.object_name como nombre totalmente cualificado del modelo en el atributo embedding_model. Si el usuario actual es el propietario del esquema o es propietario del modelo, puede omitir el nombre del esquema.

Asegúrese de tener los siguientes privilegios si un propietario de esquema diferente es propietario del modelo:
  • Privilegio del sistema CREATE ANY MINING MODEL
  • Privilegio del sistema SELECT ANY MINING MODEL
  • Privilegio de objeto SELECT MINING MODEL en el modelo específico

Para otorgar un privilegio del sistema, debe tener otorgado el privilegio del sistema con ADMIN OPTION o el privilegio del sistema GRANT ANY PRIVILEGE.

Consulte Privilegios del sistema para Oracle Machine Learning for SQL para revisar los privilegios.

Las siguientes sentencias permiten a ADB_USER1 puntuar los datos y ver los detalles del modelo en cualquier esquema siempre que se haya otorgado acceso SELECT a los datos. Sin embargo, ADB_USER1 solo puede crear modelos en el esquema ADB_USER1.

GRANT CREATE MINING MODEL TO ADB_USER1;
GRANT SELECT ANY MINING MODEL TO ADB_USER1;
BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
     profile_name => 'OCI_GENAI',
     attributes   => '{"provider": "oci",
                       "credential_name": "GENAI_CRED",
                       "vector_index_name": "MY_INDEX",
                       "embedding_model": "database: ADB_USER1.MY_ONNX_MODEL"}'
  );
END;
/

El siguiente ejemplo muestra cómo puede especificar un nombre de objeto de modelo sensible a mayúsculas/minúsculas:

BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
     profile_name => 'OCI_GENAI',
     attributes   => '{"provider": "oci",
                       "credential_name": "GENAI_CRED",
                       "model": "meta.llama-3.3-70b-instruct",
                       "vector_index_name": "MY_INDEX",
                       "embedding_model": "database: \"adb_user1\".\"my_model\""}'
  );
END;
/
Ejemplos integrales con diferentes proveedores de IA

Estos ejemplos demuestran los pasos integrales para utilizar el modelo de transformador en la base de datos con Select AI RAG. Un perfil utiliza database como provider creado exclusivamente para generar vectores de embebido, mientras que el otro perfil utiliza oci como provider creado para las acciones Select AI y el índice vectorial.

Revise Perform Prerequisites for Select AI para proporcionar los privilegios necesarios.
--Grant create any directory privilege to the user
GRANT CREATE ANY DIRECTORY to ADB_USER;

- Create a Directory object, or use an existing directory object
CREATE OR REPLACE DIRECTORY ONNX_DIR AS 'onnx_model';
 
-- Object storage bucket
VAR location_uri VARCHAR2(4000);
EXEC :location_uri := 'https://adwc4pm.objectstorage.us-ashburn-1.oci.customer-oci.com/p/eLddQappgBJ7jNi6Guz9m9LOtYe2u8LWY19GfgU8flFK4N9YgP4kTlrE9Px3pE12/n/adwc4pm/b/OML-Resources/o/';
 
-- Model file name
VAR file_name VARCHAR2(512);
EXEC :file_name := 'all_MiniLM_L12_v2.onnx';
 
-- Download ONNX model from object storage into the directory object
BEGIN
  DBMS_CLOUD.GET_OBJECT(                           
        credential_name => NULL,
        directory_name  => 'ONNX_DIR',
        object_uri      => :location_uri || :file_name);
END;
/
 
-- Load the ONNX model into the database
BEGIN
  DBMS_VECTOR.LOAD_ONNX_MODEL(
        directory  => 'ONNX_DIR',
        file_name  => :file_name,
        model_name => 'MY_ONNX_MODEL');
END;
/
 
-- Verify
SELECT model_name, algorithm, mining_function
FROM user_mining_models
WHERE  model_name='MY_ONNX_MODEL';


--Administrator grants EXECUTE privilege to ADB_USER
GRANT EXECUTE on DBMS_CLOUD_AI to ADB_USER; 

--Administrator grants EXECUTE privilege DBMS_CLOUD_PIPELINE to ADB_USER
GRANT EXECUTE on DBMS_CLOUD_PIPELINE to ADB_USER;
 
-- Create the object store credential
BEGIN
      DBMS_CLOUD.CREATE_CREDENTIAL(
        credential_name => 'OCI_CRED',
        username => '<your_username>',
        password => '<OCI_profile_password>'
      );
END;
/

PL/SQL procedure successfully completed.

 -- Create the profile with Oracle Database.

BEGIN
      DBMS_CLOUD_AI.CREATE_PROFILE(
          profile_name =>'EMBEDDING_PROFILE',
          attributes   =>'{"provider": "database",
            "embedding_model": "MY_ONNX_MODEL"
          }');
END;
/

PL/SQL procedure successfully completed.

-- Set profile
EXEC DBMS_CLOUD_AI.SET_PROFILE('EMBEDDING_PROFILE');

PL/SQL procedure successfully completed.                                            
 

En este ejemplo se utiliza oci como provider.

--Grant create any directory privilege to the user
GRANT CREATE ANY DIRECTORY to ADB_USER;

- Create a Directory object, or use an existing directory object
CREATE OR REPLACE DIRECTORY ONNX_DIR AS 'onnx_model';
 
-- Object storage bucket
VAR location_uri VARCHAR2(4000);
EXEC :location_uri := 'https://adwc4pm.objectstorage.us-ashburn-1.oci.customer-oci.com/p/eLddQappgBJ7jNi6Guz9m9LOtYe2u8LWY19GfgU8flFK4N9YgP4kTlrE9Px3pE12/n/adwc4pm/b/OML-Resources/o/';
 
-- Model file name
VAR file_name VARCHAR2(512);
EXEC :file_name := 'all_MiniLM_L12_v2.onnx';
 
-- Download ONNX model from object storage into the directory object
BEGIN
  DBMS_CLOUD.GET_OBJECT(                           
        credential_name => NULL,
        directory_name  => 'ONNX_DIR',
        object_uri      => :location_uri || :file_name);
END;
/
 
-- Load the ONNX model into the database
BEGIN
  DBMS_VECTOR.LOAD_ONNX_MODEL(
        directory  => 'ONNX_DIR',
        file_name  => :file_name,
        model_name => 'MY_ONNX_MODEL');
END;
/
 
-- Verify
SELECT model_name, algorithm, mining_function
FROM user_mining_models
WHERE  model_name='MY_ONNX_MODEL';


–-Administrator Grants EXECUTE privilege to ADB_USER
GRANT EXECUTE on DBMS_CLOUD_AI to ADB_USER; 

--Administrator Grants EXECUTE privilege DBMS_CLOUD_PIPELINE to ADB_USER
GRANT EXECUTE on DBMS_CLOUD_PIPELINE to ADB_USER;

-- Create the object store credential
BEGIN
      DBMS_CLOUD.CREATE_CREDENTIAL(
        credential_name => 'OCI_CRED',
        username => '<your_username>',
        password => '<OCI_profile_password>'
      );
END;
/
--Create GenAI credentials
BEGIN                                                                        
  DBMS_CLOUD.CREATE_CREDENTIAL(                                              
    credential_name => 'GENAI_CRED',                                         
    user_ocid       => 'ocid1.user.oc1..aaaa...',
    tenancy_ocid    => 'ocid1.tenancy.oc1..aaaa...',
    private_key     => '<your_api_key>',
    fingerprint     => '<your_fingerprint>'     
  );                                                                         
END;                                                                        
/
--Create OCI AI profile
BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
     profile_name => 'OCI_GENAI',
     attributes   => '{"provider": "oci",
                       "model": "meta.llama-3.3-70b-instruct",
                       "credential_name": "GENAI_CRED",
                       "vector_index_name": "MY_INDEX",
                       "embedding_model": "database: MY_ONNX_MODEL"}'
  );
END;
/

-- Set profile
EXEC DBMS_CLOUD_AI.SET_PROFILE('OCI_GENAI');

PL/SQL procedure successfully completed.                                            
 
-- create a vector index with the vector store name, object store location and
-- object store credential
BEGIN
       DBMS_CLOUD_AI.CREATE_VECTOR_INDEX(
         index_name  => 'MY_INDEX',
         attributes  => '{"vector_db_provider": "oracle",
                          "location": "https://swiftobjectstorage.us-phoenix-1.oraclecloud.com/v1/my_namespace/my_bucket/my_data_folder",
                          "object_storage_credential_name": "OCI_CRED",
                          "profile_name": "OCI_GENAI",
                          "vector_dimension": 384,
                          "vector_distance_metric": "cosine",
                          "chunk_overlap":128,
                          "chunk_size":1024
      }');
END;
/
PL/SQL procedure successfully completed.  
                                                                               

-- Set profile
EXEC DBMS_CLOUD_AI.SET_PROFILE('OCI_GENAI');

PL/SQL procedure successfully completed.

-- Select AI answers the question with the knowledge available in the vector database.

set pages 1000
set linesize 150
SELECT AI narrate how can I deploy an oracle machine learning model;
RESPONSE                                                  
To deploy an Oracle Machine Learning model, you would first build your model within the Oracle database. Once your in-database models are 
built, they become immediately available for use, for instance, through a SQL query using the prediction operators built into the SQL 
language. 

The model scoring, like model building, occurs directly in the database, eliminating the need for a separate engine or environment within 
which the model and corresponding algorithm code operate. You can also use models from a different schema (user account) if the appropriate 
permissions are in place.

Sources:
  - Manage-your-models-with-Oracle-Machine-Learning-on-Autonomous-Database.txt (https://objectstorage.../v1/my_namespace/my_bucket/
my_data_folder/Manage-your-models-with-Oracle-Machine-Learning-on-Autonomous-Database.txt)
  - Develop-and-deploy-machine-learning-models-using-Oracle-Autonomous-Database-Machine-Learning-and-APEX.txt 
(https://objectstorage.../v1/my_namespace/my_bucket/my_data_folder/Develop-and-deploy-machine-learning-models-using-Oracle-Autonomous-
Database-Machine-Learning-and-APEX.txt)

Ejemplo: Mejora de la generación de consultas SQL

Estos ejemplos muestran cómo los comentarios, las anotaciones, la clave ajena y las restricciones de integridad referencial en las tablas y columnas de la base de datos pueden mejorar la generación de consultas SQL a partir de peticiones de datos en lenguaje natural.

Ejemplo: Mejora de la Generación de SQL con Comentarios de Tabla y Columna

Si tiene comentarios de tabla y columna en las tablas de la base de datos, active el parámetro "comments":"true" en la función DBMS_CLOUD_AI.CREATE_PROFILE para recuperar comentarios de nivel de tabla y de columna. Los comentarios se agregan a los metadatos del LLM para una mejor generación de SQL.

-- Adding comments to table 1, table 2, and table 3. Table 1 has 3 columns, table 2 has 7 columns, table 3 has 2 columns.

-- TABLE1
COMMENT ON TABLE table1 IS 'Contains movies, movie titles and the year it was released';
COMMENT ON COLUMN table1.c1 IS 'movie ids. Use this column to join to other tables';
COMMENT ON COLUMN table1.c2 IS 'movie titles';
COMMENT ON COLUMN table1.c3 IS 'year the movie was released';
-- TABLE2
COMMENT ON TABLE table2 IS 'transactions for movie views - also known as streams';
COMMENT ON COLUMN table2.c1 IS 'day the movie was streamed';
COMMENT ON COLUMN table2.c2 IS 'genre ids. Use this column to join to other tables';
COMMENT ON COLUMN table2.c3 IS 'movie ids. Use this column to join to other tables';
COMMENT ON COLUMN table2.c4 IS 'customer ids. Use this column to join to other tables';
COMMENT ON COLUMN table2.c5 IS 'device used to stream, watch or view the movie';
COMMENT ON COLUMN table2.c6 IS 'sales from the movie';
COMMENT ON COLUMN table2.c7 IS 'number of views, watched, streamed';

-- TABLE3
COMMENT ON TABLE table3 IS 'Contains the genres';
COMMENT ON COLUMN table3.c1 IS 'genre id. use this column to join to other tables';
COMMENT ON COLUMN table3.c2 IS 'name of the genre';


BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
    profile_name => 'myprofile',
    attributes =>       
        '{"provider": "azure",
          "azure_resource_name": "my_resource",                    
          "azure_deployment_name": "my_deployment",
          "credential_name": "my_credential",
          "comments":"true", 
          "object_list": [
            {"owner": "moviestream", "name": "table1"},
            {"owner": "moviestream", "name": "table2"},
            {"owner": " moviestream", "name": "table3"}             
          ]          
          }'
    );

    DBMS_CLOUD_AI.SET_PROFILE(
        profile_name => 'myprofile'
    );

END;
/

--Prompts
select ai what are our total views;
RESPONSE
-------------------------------------------------
TOTAL_VIEWS
-----------
   97890562

select ai showsql what are our total views;

RESPONSE                                                                 
-------------------------------------------------------------------------
SELECT SUM(QUANTITY_SOLD) AS total_views
FROM "moviestream"."table"

select ai what are our total views broken out by device;

DEVICE                     TOTAL_VIEWS
-------------------------- -----------
mac                           14719238
iphone                        20793516
ipad                          15890590
pc                            14715169
galaxy                        10587343
pixel                         10593551
lenovo                         5294239
fire                           5296916

8 rows selected. 

select ai showsql what are our total views broken out by device;

RESPONSE                                                                               
---------------------------------------------------------------------------------------
SELECT DEVICE, COUNT(*) AS TOTAL_VIEWS
FROM "moviestream"."table"
GROUP BY DEVICE
Ejemplo: Mejora de la Generación de Consultas SQL con Anotaciones de Tabla y Columna

En este ejemplo se muestra la integración de anotaciones en Select AI, aplicable en Oracle Database 23ai. Las anotaciones se agregan a los metadatos que se envían al LLM.

Si tiene una tabla con anotaciones en el esquema, active "annotations":"true" en la función DBMS_CLOUD_AI.CREATE_PROFILE para indicar a Select AI que agregue anotaciones a los metadatos.

--
-- Annotations
--
 
CREATE TABLE emp2 (
    empno NUMBER,
    ename VARCHAR2(50) ANNOTATIONS (display 'lastname'),
    salary NUMBER ANNOTATIONS ("person_salary", "column_hidden"),
    deptno NUMBER ANNOTATIONS (display 'department')
)ANNOTATIONS (requires_audit 'yes', version '1.0', ówner 'HR Organization'); 
 
Table created.
 
 BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
   profile_name => 'GOOGLE_ANNOTATIONS',
   attributes   => '{"provider": "google",
      "credential_name": "GOOGLE_CRED",
      "object_list": [{"owner": "ADB_USER", "name": "emp2"}],
      "annotations" : "true"
      }');
END;
/ 
 
PL/SQL procedure successfully completed.
 
EXEC DBMS_CLOUD_AI.SET_PROFILE('GOOGLE_ANNOTATIONS');
 
PL/SQL procedure successfully completed.
Ejemplo: Mejora de la Generación de Consultas SQL con Restricciones de Clave Ajena y Clave Referencial

En este ejemplo, se muestra la capacidad del LLM para generar condiciones JOIN precisas mediante la recuperación de las restricciones de clave ajena y clave referencial en los metadatos del LLM. Las restricciones de clave ajena y clave referencial proporcionan datos de relación estructurada entre las tablas y el LLM.

Active "constraints":"true" en la función DBMS_CLOUD_AI.CREATE_PROFILE para que Select AI recupere la clave ajena y la clave referencial.

--
-- Referential Constraints
--
CREATE TABLE dept_test (
    deptno NUMBER PRIMARY KEY,
    dname VARCHAR2(50)
); 
 
Table created.
 
CREATE TABLE emp3 (
    empno NUMBER PRIMARY KEY,
    ename VARCHAR2(50),
    salary NUMBER,
    deptno NUMBER,
    CONSTRAINT emp_dept_fk FOREIGN KEY (deptno) REFERENCES dept_test(deptno)
); 
 
Table created.
 
 
BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
    profile_name=>'GOOGLE_CONSTRAINTS',
    attribues   =>'{"provider": "google",
      "credential_name": "GOOGLE_CRED",
      "object_list": [{"owner": "ADB_USER", "name": "dept_test"},
                      {"owner": "ADB_USER", "name": "emp3"}],
      "constraints" : "true"
      }');
END;
/
 
PL/SQL procedure successfully completed.
 
EXEC DBMS_CLOUD_AI.SET_PROFILE('GOOGLE_CONSTRAINTS');
 
PL/SQL procedure successfully completed.
Ejemplo: Detección Automática de Metadatos de Tabla Relevantes

En estos ejemplos se muestra cómo Select AI detecta automáticamente las tablas relevantes y envía metadatos solo para las tablas específicas relevantes para la consulta en Oracle Database 23ai. Para activar esta función, defina object_list_mode en automated. Esto crea automáticamente un índice vectorial denominado <profile_name>_OBJECT_LIST_VECINDEX. El índice vectorial se inicializa con atributos y valores por defecto, como refresh_rate, similarity_threshold y match_limit. Puede modificar algunos atributos mediante DBMS_CLOUD_AI.UPDATE_VECTOR_INDEX. Consulte Procedimiento UPDATE_VECTOR_INDEX para obtener más información.

Un perfil está configurado para utilizar object_list para especificar el esquema o los objetos del esquema, mientras que el otro no especifica object_list. Sin embargo, se espera la misma construcción SQL.

Revise Perform Prerequisites for Select AI para proporcionar acceso al paquete DBMS_CLOUD_AI y proporcionar acceso de red al proveedor de AI.

BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
    profile_name=>'OCI_AUTO',
    attributes=>'{"provider": "oci",                                                                 
      "credential_name": "GENAI_CRED",
      "object_list": [{"owner": "SH"}],
      "oci_compartment_id": "ocid1.compartment.oc1..aaaa...",
      "model" : "meta.llama-3.3-70b-instruct"
      }');
END;
/  

PL/SQL procedure successfully completed.

EXEC DBMS_CLOUD_AI.SET_PROFILE('OCI_AUTO');

PL/SQL procedure successfully completed.

select ai showsql how many customers in San Francisco are married;

RESPONSE
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SELECT COUNT(DISTINCT c."CUST_ID") AS "NUMBER_OF_CUSTOMERS"
FROM "SH"."CUSTOMERS" c
WHERE UPPER(c."CUST_CITY") = UPPER('San Francisco')
AND UPPER(c."CUST_MARITAL_STATUS") = UPPER('married')

En el siguiente ejemplo se compara el mismo escenario sin utilizar object_list. Si no especifica object_list, Select AI selecciona automáticamente todos los objetos disponibles para el esquema actual.

BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
    profile_name=>'OCI_AUTO1',
    attributes=>'{"provider": "oci",                                                                 
      "credential_name": "GENAI_CRED",
      "oci_compartment_id": "ocid1.compartment.oc1..aaaa...",
      "object_list_mode": "automated",
      "model" : "meta.llama-3.3-70b-instruct"
      }');
END;
/  
PL/SQL procedure successfully completed.

EXEC DBMS_CLOUD_AI.SET_PROFILE('OCI_AUTO1');

PL/SQL procedure successfully completed.

select ai showsql how many customers in San Francisco are married?;

RESPONSE
----------------------------------------------------------------------------------------------------------------------------------------------------------------------
SELECT COUNT(c."CUST_ID") AS "Number_of_Customers" 
FROM "SH"."CUSTOMERS" c 
WHERE UPPER(c."CUST_CITY") = UPPER('San Francisco') 
AND UPPER(c."CUST_MARITAL_STATUS") = UPPER('Married')

Ejemplo: generación de datos sintéticos

En este ejemplo se explora cómo puede generar datos sintéticos que imiten las características y la distribución de datos reales.

En el siguiente ejemplo se muestra cómo crear algunas tablas en el esquema, utilizar OCI Generative AI como proveedor de IA para crear un perfil de IA, sintetizar datos en esas tablas mediante la función DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA y consultar o generar respuestas a peticiones de datos en lenguaje natural con Select AI.

--Create tables or use cloned tables

CREATE TABLE ADB_USER.Director (
    director_id     INT PRIMARY KEY,
    name            VARCHAR(100)
);
CREATE TABLE ADB_USER.Movie (
    movie_id        INT PRIMARY KEY,
    title           VARCHAR(100),
    release_date    DATE,
    genre           VARCHAR(50),
    director_id     INT,
    FOREIGN KEY (director_id) REFERENCES ADB_USER.Director(director_id)
);
CREATE TABLE ADB_USER.Actor (
    actor_id        INT PRIMARY KEY,
    name            VARCHAR(100)
);
CREATE TABLE ADB_USER.Movie_Actor (
    movie_id        INT,
    actor_id        INT,
    PRIMARY KEY (movie_id, actor_id),
    FOREIGN KEY (movie_id) REFERENCES ADB_USER.Movie(movie_id),
    FOREIGN KEY (actor_id) REFERENCES ADB_USER.Actor(actor_id)
);

-- Create the GenAI credential
BEGIN                                                                       
  DBMS_CLOUD.create_credential(                                             
    credential_name => 'GENAI_CRED',                                        
    user_ocid       => 'ocid1.user.oc1....',
    tenancy_ocid    => 'ocid1.tenancy.oc1....',
    private_key     => 'vZ6cO...',
    fingerprint     => '86:7d:...'    
  );                                                                        
END;                                                                       
/
 
-- Create a profile
BEGIN                                                                      
  DBMS_CLOUD_AI.CREATE_PROFILE(                                            
      profile_name =>'GENAI',                                                           
      attributes  =>'{"provider": "oci",                                                                 
        "credential_name": "GENAI_CRED",                                   
        "object_list": [{"owner": "ADB_USER", 
		"oci_compartment_id": "ocid1.compartment.oc1...."}]          
       }');                                                                
END;                                                                       
/
 
 
EXEC DBMS_CLOUD_AI.set_profile('GENAI');

-- Run the API for single table
BEGIN
    DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
        profile_name => 'GENAI',
        object_name  => 'Director',
        owner_name   => 'ADB_USER',
        record_count => 5
    );
END;
/
PL/SQL procedure successfully completed.
 
 
-- Query the table to see results
SQL> SELECT * FROM ADB_USER.Director;
 
DIRECTOR_ID NAME
----------- ----------------------------------------------------------------------------------------------------
          1 John Smith
          2 Emily Chen
          3 Michael Brown
          4 Sarah Taylor
          5 David Lee
 
 
-- Or ask select ai to show the results
SQL> select ai how many directors are there;
 
NUMBER_OF_DIRECTORS
-------------------
                  5
Ejemplo: generación de datos sintéticos para varias tablas

Después de crear y definir el perfil de proveedor de AI, utilice DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA para generar datos para varias tablas. Puede consultar o utilizar Select AI para responder a las peticiones de datos en lenguaje natural.

BEGIN
    DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
        profile_name => 'GENAI',
        object_list => '[{"owner": "ADB_USER", "name": "Director","record_count":5},
                         {"owner": "ADB_USER", "name": "Movie_Actor","record_count":5},
                         {"owner": "ADB_USER", "name": "Actor","record_count":10},
                         {"owner": "ADB_USER", "name": "Movie","record_count":5,"user_prompt":"all movies released in 2009"}]'
    );
END;
/
PL/SQL procedure successfully completed.
 
 
-- Query the table to see results
SQL> select * from ADB_USER.Movie;

 MOVIE_ID TITLE                                                     RELEASE_D                            GENRE                                 DIRECTOR_ID	
---------- -------------------------------------------------------- --------- --------------------------------------------------------------- -----------	
         1 The Dark Knight                                           15-JUL-09                              Action                              8	
         2 Inglourious Basterds                                      21-AUG-09                              War                                 3	
         3 Up in the Air                                             04-SEP-09                              Drama                               6	
         4 The Hangover                                              05-JUN-09                              Comedy                              1	
         5 District 9                                                14-AUG-09                              Science Fiction                     10	
	

 
-- Or ask select ai to show the results
SQL> select ai how many actors are there;
 
Number of Actors
----------------
              10
Ejemplo: guía de generación de datos sintéticos con filas de ejemplo

Para guiar el servicio de IA en la generación de datos sintéticos, puede seleccionar de forma aleatoria registros existentes de una tabla. Por ejemplo, al agregar {"sample_rows": 5} al argumento params, puede enviar 5 filas de ejemplo de una tabla al proveedor de AI. En este ejemplo se generan 10 filas adicionales basadas en las filas de ejemplo de la tabla Transactions.

BEGIN
  DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
    profile_name => 'GENAI',
    object_name  => 'Transactions',
    owner_name   => 'ADB_USER',
    record_count => 10,
    params       => '{"sample_rows":5}'
  );
END;
/
Ejemplo: Personalización de la generación de datos sintéticos con peticiones de datos de usuario

El argumento user_prompt permite especificar reglas o requisitos adicionales para la generación de datos. Esto se puede aplicar a una sola tabla o como parte del argumento object_list para varias tablas. Por ejemplo, en las siguientes llamadas a DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA, la petición de datos indica a AI que genere datos sintéticos sobre películas lanzadas en 2009.

-- Definition for the Movie table CREATE TABLE Movie 

CREATE TABLE Movie (
    movie_id        INT PRIMARY KEY,
    title           VARCHAR(100),
    release_date    DATE,
    genre           VARCHAR(50),
    director_id     INT,
    FOREIGN KEY (director_id) REFERENCES Director(director_id)
);
 
 
 
BEGIN
  DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
    profile_name      => 'GENAI',
    object_name       => 'Movie',
    owner_name        => 'ADB_USER',
    record_count      => 10,
    user_prompt       => 'all movies are released in 2009',
    params            => '{"sample_rows":5}'
  );
END;
/
 
BEGIN
    DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
        profile_name => 'GENAI',
        object_list => '[{"owner": "ADB_USER", "name": "Director","record_count":5},
                         {"owner": "ADB_USER", "name": "Movie_Actor","record_count":5},
                         {"owner": "ADB_USER", "name": "Actor","record_count":10},
                         {"owner": "ADB_USER", "name": "Movie","record_count":5,"user_prompt":"all movies are released in 2009"}]'
    );
END;
/
Ejemplo: Mejora de la Calidad de los Datos Sintéticos mediante Estadísticas de Tabla

Si una tabla tiene estadísticas de columna o se clona a partir de una base de datos que incluye metadatos, Select AI puede utilizar estas estadísticas para generar datos que se parezcan o sean coherentes con los datos originales.

Para las columnas NUMBER, los valores alto y bajo de las estadísticas guían el rango de valores. Por ejemplo, si la columna SALARY de la tabla EMPLOYEES original oscila entre 1000 y 10000, los datos sintéticos de esta columna también estarán dentro de este rango.

Para las columnas con valores distintos, como una columna STATE con los valores CA, WA y TX, los datos sintéticos utilizarán estos valores específicos. Puede gestionar esta función mediante el parámetro {"table_statistics": true/false}. Por defecto, las estadísticas de la tabla están activadas.

BEGIN
  DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
    profile_name      => 'GENAI',
    object_name       => 'Movie',
    owner_name        => 'ADB_USER',
    record_count      => 10,
    user_prompt => 'all movies released in 2009',
    params            => '{"sample_rows":5,"table_statistics":true}'
  );
END;
/
Ejemplo: uso de comentarios de columna para guiar la generación de datos

Si existen comentarios de columna, Select AI los incluye automáticamente para proporcionar información adicional para el LLM durante la generación de datos. Por ejemplo, un comentario en la columna Status de una tabla de transacciones puede mostrar valores permitidos, como successful, failed, pending, canceled y need manual check. También puede agregar comentarios para explicar más detalladamente la columna, dando a los servicios de IA instrucciones o sugerencias más precisas para generar datos precisos. Por defecto, los comentarios están desactivados. Consulte Parámetros opcionales para obtener más información.

-- Use comment on column
COMMENT ON COLUMN Transaction.status IS 'the value for state should either be ''successful'', ''failed'', ''pending'' or ''canceled''';
/
 
BEGIN
    DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
        profile_name  => 'GENAI',
        object_name   => 'employees',
        owner_name    => 'ADB_USER',
        record_count  => 10
        params        => '{"comments":true}'
 
    );
END;
/
Ejemplo: definición de valores únicos en la generación de datos sintéticos

Al generar grandes cantidades de datos sintéticos con LLM, es probable que se produzcan valores duplicados. Para evitarlo, configure una restricción única en la columna relevante. Esto garantiza que Select AI ignore las filas con valores duplicados en la respuesta del LLM. Además, para restringir valores para determinadas columnas, puede utilizar user_prompt o agregar comentarios para especificar los valores permitidos, como limitar una columna STATE a CA, WA y TX.

-- Use 'user_prompt'
BEGIN
    DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
        profile_name  => 'GENAI',
        object_name   => 'employees',
        owner_name    => 'ADB_USER',
        user_prompt   => 'the value for state should either be CA, WA, or TX',
        record_count  => 10
    );
END;
/
 
 
-- Use comment on column
COMMENT ON COLUMN EMPLOYEES.state IS 'the value for state should either be CA, WA, or TX'
/
Ejemplo: Mejora de la generación de datos sintéticos mediante procesamiento paralelo

Para reducir el tiempo de ejecución, Select AI divide las tareas de generación de datos sintéticos en fragmentos más pequeños para tablas sin claves primarias o con claves primarias numéricas. Estas tareas se ejecutan en paralelo, interactuando con el proveedor de IA para generar datos de manera más eficiente. El grado de paralelismo (DOP) de la base de datos, influenciado por el nivel de servicio de Autonomous Database y la configuración de ECPU u OCPU, determina el número de registros de cada proceso de fragmento. La ejecución de tareas en paralelo generalmente mejora el rendimiento, especialmente al generar grandes cantidades de datos en muchas tablas. Para gestionar el procesamiento paralelo de la generación de datos sintéticos, defina priority como parámetro opcional. Consulte Optional Parameters.

Ejemplo: activación o desactivación del acceso a datos

En este ejemplo, se muestra cómo los administradores pueden controlar el acceso a los datos y evitar que Select AI envíe tablas de esquema reales al LLM.

Desactivación del acceso a datos

Para restringir el acceso a las tablas de esquema, conéctese como administrador y ejecute el siguiente procedimiento.

EXEC DBMS_CLOUD_AI.DISABLE_DATA_ACCESS;
 
PL/SQL procedure successfully completed.

Desactivación de los límites de acceso a datos Seleccione la acción narrate de AI y la generación de datos sintéticos. La acción narrate y la generación de datos sintéticos generan un error.

Conéctese como usuario de base de datos, cree y configure su perfil de AI. Revise Perform Prerequisites for Select AI para configurar su perfil de AI.

BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
          profile_name =>'DATA_ACCESS',
          attributes   =>'{"provider": "openai",
            "credential_name": "OPENAI_CRED",
            "object_list": [{"owner":"SH"}]
          }');
END;
/

EXEC DBMS_CLOUD_AI.SET_PROFILE('DATA_ACCESS');
 

select ai how many customers;

NUM_CUSTOMERS
55500

select ai narrate what are the top 3 customers in San Francisco;

ORA-20000: Data access is disabled for SELECT AI.
ORA-06512: at "C##CLOUD$SERVICE.DBMS_CLOUD", line 2228
ORA-06512: at "C##CLOUD$SERVICE.DBMS_CLOUD_AI", line 13157
ORA-06512: at line 1 https://docs.oracle.com/error-help/db/ora-20000/
The stored procedure 'raise_application_error' was called which causes this error to be generated
Error at Line: 1 Column: 6

El siguiente ejemplo muestra los errores que se disparan al intentar generar datos sintéticos.

BEGIN
DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
profile_name => 'DATA_ACCESS_SDG',
object_name => 'CUSTOMERS_NEW',
owner_name => 'ADB_USER,
record_count => 5
);
END;
/ 

ERROR at line 1:

ORA-20000: Data access is disabled for SELECT AI.
ORA-06512: at "C##CLOUD$SERVICE.DBMS_CLOUD", line 2228
ORA-06512: at "C##CLOUD$SERVICE.DBMS_CLOUD_AI", line 13401

ORA-06512: at line 2
Activación del acceso a datos

En el siguiente ejemplo, se muestra cómo activar el acceso a datos. Inicie sesión como administrador y ejecute el siguiente procedimiento:

EXEC DBMS_CLOUD_AI.ENABLE_DATA_ACCESS;
 
PL/SQL procedure successfully completed.

Conéctese como usuario de base de datos, cree y configure su perfil de AI. Revise Perform Prerequisites for Select AI para configurar su perfil de AI. Ejecute la acción narrate y genere datos sintéticos por separado.

BEGIN
  DBMS_CLOUD_AI.CREATE_PROFILE(
          profile_name =>'DATA_ACCESS_NEW',
          attributes   =>'{"provider": "openai",
            "credential_name": "OPENAI_CRED",
            "object_list": [{"owner":"SH"}]
          }');
   END;
   /

PL/SQL procedure successfully completed.

EXEC DBMS_CLOUD_AI.SET_PROFILE('DATA_ACCESS_NEW');

PL/SQL procedure successfully completed.


select ai how many customers;

NUM_CUSTOMERS
55500

select ai narrate what are the top 3 customers in San Francisco;

"RESPONSE"
"The top 3 customers in San Francisco are Cody Seto, Lauren Yaskovich, and Ian Mc"

El siguiente ejemplo muestra la generación correcta de datos sintéticos después de activar el acceso a datos.

BEGIN
DBMS_CLOUD_AI.GENERATE_SYNTHETIC_DATA(
profile_name => 'DATA_ACCESS_SDG',
object_name => 'CUSTOMERS_NEW',
owner_name => 'ADB_USER',
record_count => 5
);
END;
/ 

PL/SQL procedure successfully completed.

Ejemplo: restricción del acceso a tablas en el perfil de AI

En este ejemplo, se muestra cómo restringir el acceso a tablas e indicar al LLM que utilice solo las tablas especificadas en object_list del perfil AI.

Defina enforce_object_list en true para restringir el acceso a la tabla al LLM.

Como usuario de base de datos, cree y configure su perfil de AI. Revise Perform Prerequisites for Select AI para configurar su perfil de AI.

BEGIN
      DBMS_CLOUD_AI.CREATE_PROFILE(
        profile_name =>'GOOGLE_ENFORCED',
        attributes   =>'{"provider": "google",
          "credential_name": "GOOGLE_CRED",
          "object_list": [{"owner": "ADB_USER", "name": "GENRE"},
                  {"owner": "ADB_USER", "name": "CUSTOMER"},
                  {"owner": "ADB_USER", "name": "PIZZA_SHOP"},
                  {"owner": "ADB_USER", "name": "STREAMS"},
                  {"owner": "ADB_USER", "name": "MOVIES"},
                  {"owner": "ADB_USER", "name": "ACTIONS"}],
          "enforce_object_list" : "true"
          }');
END;
/
 
PL/SQL procedure successfully completed.
 

EXEC DBMS_CLOUD_AI.set_profile('GOOGLE_ENFORCED');
 
PL/SQL procedure successfully completed.
 
select ai showsql please list the user tables;
 
RESPONSE
--------------------------------------------------------------------------------------------
SELECT 'ADB_USER.GENRE' AS TABLE_NAME FROM DUAL UNION ALL SELECT 'ADB_USER.CUSTOMER' AS 
TABLE_NAME FROM DUAL UNION ALL SELECT 'ADB_USER.PIZZA_SHOP' AS TABLE_NAME FROM DUAL UNION
 ALL SELECT 'ADB_USER.STREAMS' AS TABLE_NAME FROM DUAL UNION ALL SELECT 'ADB_USER.MOVIES' 
AS TABLE_NAME FROM DUAL 
--

Si se define enforce_object_list en false, se indica al LLM que utilice otras tablas y vistas según sus conocimientos anteriores.

BEGIN
      DBMS_CLOUD_AI.CREATE_PROFILE(
        profile_name =>'GOOGLE_ENFORCED1',
        attributes   =>'{"provider": "google",
          "credential_name": "GOOGLE_CRED",
          "object_list": [{"owner": "ADB_USER", "name": "GENRE"},
                  {"owner": "ADB_USER", "name": "CUSTOMER"},
                  {"owner": "ADB_USER", "name": "PIZZA_SHOP"},
                  {"owner": "ADB_USER", "name": "STREAMS"},
                  {"owner": "ADB_USER", "name": "MOVIES"},
                  {"owner": "ADB_USER", "name": "ACTIONS"}],
          "enforce_object_list" : "false"
          }');
END;
/
 
PL/SQL procedure successfully completed.
 

EXEC DBMS_CLOUD_AI.set_profile('GOOGLE_ENFORCED1');
 
PL/SQL procedure successfully completed.
 
select ai showsql please list the user tables;
RESPONSE
----------------------------------
SELECT TABLE_NAME FROM USER_TABLES

Ejemplo: especificación de la distinción entre mayúsculas y minúsculas para columnas

En este ejemplo, se muestra cómo puede definir la distinción entre mayúsculas y minúsculas para columnas en el perfil de AI.

Defina case_sensitive_values en false para recuperar consultas que no sean sensibles a mayúsculas/minúsculas.

Como usuario de base de datos, cree y configure su perfil de AI. Revise Perform Prerequisites for Select AI para configurar su perfil de AI.

BEGIN
      DBMS_CLOUD_AI.create_profile(
        profile_name   =>'GOOGLE',
        attributes     =>'{"provider": "google",
          "credential_name": "GOOGLE_CRED",
          "object_list": [{"owner": "ADB_USER", "name": "GENRE"},
                  {"owner": "ADB_USER", "name": "CUSTOMER"},
                  {"owner": "ADB_USER", "name": "PIZZA_SHOP"},
                  {"owner": "ADB_USER", "name": "STREAMS"},
                 {"owner": "ADB_USER", "name": "MOVIES"},
                 {"owner": "ADB_USER", "name": "ACTIONS"}],
         "case_sensitive_values" : "false"
         }');
 END;
 /
 
PL/SQL procedure successfully completed.
 
-- With "case_sensitive_values" set to "false", LLM will give back case insensitive query.

select ai showsql how many people watch Inception;
 
RESPONSE
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SELECT COUNT(DISTINCT c.CUSTOMER_ID) AS "COUNT"
FROM "ADB_USER"."CUSTOMER" c
JOIN "ADB_USER"."STREAMS" s ON c.CUSTOMER_ID = s.CUSTOMER_ID
JOIN "ADB_USER"."MOVIES" m ON s.MOVIE_ID = m.MOVIE_ID
WHERE UPPER(m.TITLE) = UPPER('Inception')

Puede especificar una consulta sensible a mayúsculas/minúsculas mediante comillas dobles aunque case_sensitive_values esté definido en false.

select ai showsql how many people watch "Inception";
 
RESPONSE
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SELECT COUNT(DISTINCT c.CUSTOMER_ID) AS "COUNT" 
FROM "ADB_USER"."CUSTOMER" c JOIN "ADB_USER"."STREAMS" s ON 
c.CUSTOMER_ID = s.CUSTOMER_ID JOIN "ADB_USER"."MOVIES" m ON 
s.MOVIE_ID = m.MOVIE_ID WHERE m.TITLE = 'Inception'