Skip to content

Commit 825b8dd

Browse files
authored
Add files via upload
Initial commit for APEX plug-in examples
1 parent 8e8dc2f commit 825b8dd

File tree

6 files changed

+12463
-0
lines changed

6 files changed

+12463
-0
lines changed

apex/plugins/README.md

+9
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,9 @@
1+
# Plug-In examples
2+
3+
This directory contains examples for APEX Plug-Ins.
4+
5+
| Repo/Folder name | Description |
6+
| ------------- | ------------- |
7+
| [rest-source](./rest-source) | REST Source Plug-Ins |
8+
9+

apex/plugins/rest-source/README.md

+5
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,5 @@
1+
# REST Data Source Plug-In examples
2+
3+
This directory contains examples for REST Data Source Plug-Ins.
4+
5+
- Example plug-in which shows how to implement pagination for a REST API using a fixed page size and a page number parameter.
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,30 @@
1+
This example plug-in demonstrates how to implement pagination support for a REST API which uses a fixed page size
2+
and URL parameter for the page number. The plug-in uses "api.themoviedb.org" as example REST API.
3+
4+
### PREREQUISITES
5+
6+
To use the "themoviedb.org" REST API, you need an API key. Register for an account on themoviedb.org in order to get
7+
the API key.
8+
9+
### USAGE
10+
11+
* Create an application
12+
* Import the Plug-In in Shared Components - Plug-Ins
13+
* Create a new REST Data Source in Shared Components - REST Data Sources
14+
* Make sure to use the new Plug-In type as the REST Data Source Type
15+
* On the Authentication screen, pick "URL Query String" as the credential type, use **api_key** as name and your
16+
themoviedb.org API Key as the value
17+
* Click **Discover** and when you see sample data, click **Create** to create the REST Data Source
18+
* Create a new page in your application and add an **Interactive Report** with the new REST Data Source as
19+
its data source.
20+
* Run the page. The report should show no contents. Type in a search in order to see data from the "themoviedb.org"
21+
REST API in your APEX application.
22+
23+
Note that the Plug-In does not execute a REST request if no search term (module parameter **query**) is passed in.
24+
25+
### DISCLAIMER
26+
27+
* These scripts are provided for educational purposes only.
28+
* They are NOT supported by Oracle World Wide Technical Support.
29+
* The scripts have been tested and they appear to work as intended.
30+
* You should always run scripts on a test instance.
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,291 @@
1+
--==============================================================================
2+
type t_summary is record(
3+
page number,
4+
total_results number,
5+
total_pages number );
6+
7+
--==============================================================================
8+
-- this function extracts result set information from the response JSON received
9+
-- from the "themoviedb.org" REST API. Each JSON response contains information
10+
-- about the total amount of pages, the page returned and the total amount of
11+
-- results.
12+
--
13+
-- {"page":1,"total_results":84,"total_pages":5,"results":[{ ... }]}
14+
--==============================================================================
15+
function get_summary( p_response clob ) return t_summary
16+
is
17+
l_summary t_summary;
18+
begin
19+
select page,
20+
total_results,
21+
total_pages
22+
into l_summary.page,
23+
l_summary.total_results,
24+
l_summary.total_pages
25+
from json_table( p_response,
26+
'$'
27+
columns (
28+
page number path '$.page',
29+
total_results number path '$.total_results',
30+
total_pages number path '$.total_pages' ) );
31+
return l_summary;
32+
end get_summary;
33+
34+
--==============================================================================
35+
-- REST Source Capabilities Procedure
36+
--
37+
-- This procedure tells APEX whether the Plug-In (and the REST API) supports
38+
-- pagination (large result sets come as multiple pages), server-side filtering
39+
-- and server-side ordering.
40+
--
41+
-- The procedure implementation simply sets the "filtering", "pagination" or
42+
-- "order_by" members of the apex_plugin.t_web_source_capabilities record type
43+
-- to either true or false.
44+
--
45+
-- This plug-in supports the "themoviedb.org" pagination logic. Server Side
46+
-- filtering or ordering are not supported.
47+
--==============================================================================
48+
procedure capabilities_themoviedb (
49+
p_plugin in apex_plugin.t_plugin,
50+
p_result in out nocopy apex_plugin.t_web_source_capabilities )
51+
is
52+
begin
53+
p_result.filtering := false;
54+
p_result.pagination := true;
55+
p_result.order_by := false;
56+
end capabilities_themoviedb;
57+
58+
--==============================================================================
59+
-- REST Source Discovery Procedure
60+
--
61+
-- This procedure is called by APEX during the REST Data Source creation, when
62+
-- the "Discover" button is clicked. This procedure can:
63+
-- * return structured information about the columns, data types and
64+
-- JSON or XML selectors
65+
-- * return a JSON example which APEX then will sample to derive columns and
66+
-- data types
67+
--==============================================================================
68+
procedure discover_themoviedb (
69+
p_plugin in wwv_flow_plugin_api.t_plugin,
70+
p_web_source in wwv_flow_plugin_api.t_web_source,
71+
p_params in wwv_flow_plugin_api.t_web_source_discover_params,
72+
p_result in out nocopy wwv_flow_plugin_api.t_web_source_discover_result )
73+
is
74+
l_web_source_operation apex_plugin.t_web_source_operation;
75+
l_dummy_parameters apex_plugin.t_web_source_parameters;
76+
l_in_parameters apex_plugin.t_web_source_parameters;
77+
l_time_budget number;
78+
79+
l_param_idx pls_integer;
80+
81+
c_query_param_name constant varchar2(5) := 'query';
82+
-- the default query to perform discovery is "star trek"
83+
l_query_param_value varchar2(255) := 'star trek';
84+
l_has_query_param boolean := false;
85+
begin
86+
--
87+
-- discovery is based on the "fetch rows" operation of a REST Data Source; this is typically
88+
-- a GET operation. POST is also possible, but that must be configured in Shared Components
89+
-- REST Data Sources, Operations, Fetch Rows.
90+
--
91+
-- This gets all meta data on the REST Operation as an instance of APEX_PLUGIN.T_WEB_SOURCE_OPERATION.
92+
-- The P_PERFORM_INIT parameter determines whether APEX should compute the URL and initialize all
93+
-- HTTP Headers and parameters with their default values. The "l_web_source_operation" represents
94+
-- all attributes of the HTTP operation to be made.
95+
--
96+
l_web_source_operation := apex_plugin_util.get_web_source_operation(
97+
p_web_source => p_web_source,
98+
p_db_operation => apex_plugin.c_db_operation_fetch_rows,
99+
p_perform_init => true );
100+
101+
--
102+
-- This section copies the parameters, which we receive from the Create REST data source
103+
-- wizard, to the "l_in_parameters" array. If a "query" parameter has been defined, we'll
104+
-- memorize the value and we'll use the default if no value was provided.
105+
--
106+
for i in 1 .. l_web_source_operation.parameters.count loop
107+
l_in_parameters( l_in_parameters.count + 1 ) := l_web_source_operation.parameters( i );
108+
if l_web_source_operation.parameters( i ).name = c_query_param_name then
109+
l_query_param_value := nvl( l_web_source_operation.parameters( i ).value, l_query_param_value );
110+
l_has_query_param := true;
111+
end if;
112+
end loop;
113+
114+
--
115+
-- if the "query" parameter was provided by the developer, add it.
116+
--
117+
if not l_has_query_param then
118+
l_param_idx := l_in_parameters.count + 1;
119+
l_in_parameters( l_param_idx ).name := c_query_param_name;
120+
l_in_parameters( l_param_idx ).param_type := wwv_flow_plugin_api.c_web_src_param_query;
121+
end if;
122+
123+
--
124+
-- adjust the query string attribute of the REST operation to use the computed query parameter
125+
--
126+
l_web_source_operation.query_string := c_query_param_name || '=' || sys.utl_url.escape( l_query_param_value );
127+
128+
--
129+
-- perform the REST request. We'll receive the JSON response in the "p_result.sample_response"
130+
-- variable.
131+
--
132+
apex_plugin_util.make_rest_request(
133+
p_web_source_operation => l_web_source_operation,
134+
p_bypass_cache => false,
135+
--
136+
p_time_budget => l_time_budget,
137+
--
138+
p_response => p_result.sample_response,
139+
p_response_parameters => l_dummy_parameters );
140+
141+
-- set the response headers received by the REST API for display in the Discovery Results screen
142+
p_result.response_headers := apex_web_service.g_headers;
143+
-- "api.themoviedb.org" uses a fixed page size of 20 results
144+
p_result.fixed_page_size := 20;
145+
-- the "query" parameter can also be used for "row searches" (see REST Data Source Parameters)
146+
p_result.row_search_param_name := 'query';
147+
-- Computed Parameters to pass back to APEX
148+
p_result.parameters := l_in_parameters;
149+
end discover_themoviedb;
150+
151+
--==============================================================================
152+
-- REST Source Fetch Procedure
153+
--
154+
-- This procedure does the actual "Fetch" operation when rows are being
155+
-- requested from the REST Data Source. When an APEX component is about to
156+
-- render, APEX computes the first row and the amount of rows required. This
157+
-- and all dynamic filter and order by information is passed to the
158+
-- procedure as the "p_params" parameter.
159+
--==============================================================================
160+
procedure fetch_themoviedb (
161+
p_plugin in apex_plugin.t_plugin,
162+
p_web_source in apex_plugin.t_web_source,
163+
p_params in apex_plugin.t_web_source_fetch_params,
164+
p_result in out nocopy apex_plugin.t_web_source_fetch_result )
165+
is
166+
l_web_source_operation apex_plugin.t_web_source_operation;
167+
168+
l_time_budget number;
169+
l_summary t_summary;
170+
l_page_id pls_integer;
171+
l_start_page_id pls_integer;
172+
l_continue_fetching boolean := true;
173+
l_page_to_fetch pls_integer := 0;
174+
175+
c_page_size pls_integer := coalesce( p_params.fixed_page_size, 20 );
176+
177+
l_query_string varchar2(32767);
178+
begin
179+
--
180+
-- This gets all meta data on the REST Operation as an instance of APEX_PLUGIN.T_WEB_SOURCE_OPERATION.
181+
-- The P_PERFORM_INIT parameter determines whether APEX should compute the URL and initialize all
182+
-- HTTP Headers and parameters with their default values, from the REST Data Source configuration.
183+
-- The "l_web_source_operation" thus represents all attributes of the HTTP operation to be made.
184+
--
185+
l_web_source_operation := apex_plugin_util.get_web_source_operation(
186+
p_web_source => p_web_source,
187+
p_db_operation => apex_plugin.c_db_operation_fetch_rows,
188+
p_perform_init => true );
189+
190+
-- Initialize the response output. An invocation of the "Fetch" procedure can also return multiple
191+
-- JSON or XML documents, so responses are maintained as an instance of the APEX_T_CLOB (array of CLOB) type
192+
p_result.responses := apex_t_clob();
193+
194+
-- compute the first page to be fetched, based on the "first" row information which we receive
195+
-- from APEX. The page size is contained in the "fixed_page_size" attribute of "p_params". Discovery
196+
-- sets this to 20. For the case that developers clear this value in REST Data Source operation settings,
197+
-- we use "20" when NULL.
198+
l_start_page_id := case when p_params.fetch_all_rows then 1 else floor( ( p_params.first_row - 1 ) / c_page_size ) + 1 end;
199+
200+
-- start fetching with the first page to be fetched
201+
l_page_id := l_start_page_id;
202+
-- memorize the query string from default REST Data Source settings
203+
l_query_string := l_web_source_operation.query_string;
204+
205+
--
206+
-- check whether the "query" parameter has a value. If not (empty query), we do not reach out to the
207+
-- REST API at all. For an empty query, api.themoviedb.org would return an error response; so it does
208+
-- not make any sense to perform the call. Instead, we simply return an empty JSON response ({}).
209+
--
210+
for i in 1 .. l_web_source_operation.parameters.count loop
211+
if l_web_source_operation.parameters( i ).name = 'query' and l_web_source_operation.parameters( i ).value is null then
212+
p_result.has_more_rows := false;
213+
p_result.response_row_count := 0;
214+
p_result.response_first_row := 0;
215+
p_result.responses.extend( 1 );
216+
p_result.responses( 1 ) := to_clob( '{}');
217+
return;
218+
end if;
219+
end loop;
220+
221+
--
222+
-- if we are fetching all rows, fetch until the time budget is exhausted
223+
--
224+
while l_continue_fetching and coalesce( l_time_budget, 1 ) > 0 loop
225+
226+
-- add a new member to the array of CLOB responses
227+
p_result.responses.extend( 1 );
228+
l_page_to_fetch := l_page_to_fetch + 1;
229+
230+
--
231+
-- build the query string by using the operation attribute and appending the page to fetch
232+
-- query string example is: "query=star%20trek&page=2"
233+
--
234+
l_web_source_operation.query_string := l_query_string || 'page=' || l_page_id ;
235+
236+
--
237+
-- perform the REST request. We'll receive the JSON response in the "p_result.sample_response"
238+
-- variable.
239+
--
240+
apex_plugin_util.make_rest_request(
241+
p_web_source_operation => l_web_source_operation,
242+
p_bypass_cache => false,
243+
--
244+
p_time_budget => l_time_budget,
245+
--
246+
p_response => p_result.responses( l_page_to_fetch ),
247+
p_response_parameters => p_result.out_parameters );
248+
249+
--
250+
-- call "get_summary" in order to retrieve the total amount of pages and the total amount
251+
-- of results, so that we know whether there are more pages ot not.
252+
--
253+
l_summary := get_summary( p_result.responses( l_page_to_fetch ) );
254+
255+
--
256+
-- if APEX requested "all rows" from the REST API and there are more rows to fetch,
257+
-- then continue fetching the next page
258+
--
259+
l_continue_fetching := p_params.fetch_all_rows and l_summary.page < l_summary.total_pages;
260+
261+
-- increase the page ID counter
262+
if l_continue_fetching then
263+
l_page_id := l_page_id + 1;
264+
end if;
265+
end loop;
266+
267+
--
268+
if p_params.fetch_all_rows then
269+
270+
-- if APEX requested (and our logic fetched) all rows, then there are no more rows to fetch
271+
p_result.has_more_rows := false;
272+
-- the JSON responses contains the total amount of rows
273+
p_result.response_row_count := l_summary.total_results;
274+
-- the first row in the JSON responses is "1"
275+
p_result.response_first_row := 1;
276+
else
277+
-- APEX did _not_ request all rows, so there might be another page. If the current page number is
278+
-- below the amount of total pages, then there are more rows to fetch
279+
p_result.has_more_rows := l_summary.page < l_summary.total_pages;
280+
281+
-- The JSON responses contain 20 rows (fixed page size) if there are more pages to fetch. If
282+
-- we fetched the last page, we need to compute the amount of rows on that page.
283+
p_result.response_row_count := case when l_summary.page < l_summary.total_pages
284+
then c_page_size
285+
else l_summary.total_results - ( ( l_summary.page - 1 ) * c_page_size )
286+
end;
287+
288+
-- the first row in the JSON response depends on the page we started fetching with.
289+
p_result.response_first_row := ( l_start_page_id - 1 ) * c_page_size + 1;
290+
end if;
291+
end fetch_themoviedb;

0 commit comments

Comments
 (0)