PostgreSQL - generar funciones I

 
Vista:
Imágen de perfil de outrera

generar funciones I

Publicado por outrera (35 intervenciones) el 01/04/2014 15:34:29
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
--
-- TOC entry 456 (class 1255 OID 25113)
-- Name: psp_crear_crud(character varying); Type: FUNCTION; Schema: utils; Owner: postgres
--
 
CREATE FUNCTION psp_crear_crud(p_schemaname character varying) RETURNS void
    LANGUAGE plpgsql
    AS $$
DECLARE
	oTableDef REFCURSOR ;
	oRecord record;
	oFunctionName character varying;
	oExisteFuncion boolean;
BEGIN
 
	OPEN oTableDef FOR SELECT  utils.psp_listar_tablas(p_schemaName);
	FETCH oTableDef INTO oTableDef;
 
	-- LISTA DE TABLAS
	LOOP
	    FETCH oTableDef INTO oRecord ;
 
		IF NOT FOUND THEN
			EXIT ;
		END IF;
		-- Generar listar por id
		oFunctionName :=  'pss_listar_' || oRecord.tableName ||'_id' ;
		IF NOT utils.psp_verificar_funcion(oRecord.schemaName,oFunctionName) THEN
			PERFORM utils.psp_crear_listar_id(oRecord.schemaName,oRecord.tableName) ;
		END IF;
 
		-- Generar listar
		oFunctionName :=  'pss_listar_' || oRecord.tableName  ;
		IF NOT utils.psp_verificar_funcion(oRecord.schemaName,oFunctionName) THEN
			PERFORM utils.psp_crear_listar(oRecord.schemaName,oRecord.tableName) ;
		END IF;
 
 
		-- Generar listar paginado
		oFunctionName :=  'pss_listar_' || oRecord.tableName ||'_pg' ;
		IF NOT utils.psp_verificar_funcion(oRecord.schemaName,oFunctionName) THEN
			PERFORM utils.psp_crear_listar_pg(oRecord.schemaName,oRecord.tableName) ;
		END IF;
 
 
 
		-- Generar Insert
		oFunctionName := 'psi_' || oRecord.tableName  ;
		IF NOT utils.psp_verificar_funcion(oRecord.schemaName,oFunctionName) THEN
			PERFORM utils.psp_crear_insert(oRecord.schemaName,oRecord.tableName) ;
		END IF;
 
 
		-- Generar Update
		oFunctionName :=  'psu_' || oRecord.tableName  ;
		IF NOT utils.psp_verificar_funcion(oRecord.schemaName,oFunctionName) THEN
			PERFORM utils.psp_crear_update(oRecord.schemaName,oRecord.tableName) ;
		END IF;
 
		-- Generar Delete
		oFunctionName :=  'psd_' || oRecord.tableName  ;
		IF NOT utils.psp_verificar_funcion(oRecord.schemaName,oFunctionName) THEN
			PERFORM utils.psp_crear_delete(oRecord.schemaName,oRecord.tableName) ;
		END IF;
 
		--select *  into oExisteFuncion from utils.psp_verificar_funcion(oRecord.schemaName,oFunctionName);
 
		--RAISE NOTICE ' nombre funcion %', oFunctionName ;
		--RAISE NOTICE ' existe funcion %', oExisteFuncion ;
 
 
	END LOOP ;
 
	CLOSE oTableDef ;
 
END;
 
 
$$;
 
 
ALTER FUNCTION utils.psp_crear_crud(p_schemaname character varying) OWNER TO postgres;
 
--
-- TOC entry 522 (class 1255 OID 24895)
-- Name: psp_crear_delete(character varying, character varying); Type: FUNCTION; Schema: utils; Owner: postgres
--
 
CREATE FUNCTION psp_crear_delete(p_schemaname character varying, p_tablename character varying) RETURNS void
    LANGUAGE plpgsql
    AS $$
DECLARE
	oRecord		RECORD;
	oTableDef	REFCURSOR;
 
	oFunctionBody 	    VARCHAR;
	oSQLCommand	    VARCHAR;
	oFilter		    VARCHAR;
	oParameterList	    VARCHAR;
	--oFieldNameList	    VARCHAR;
	oPrimaryKeyName     VARCHAR;
 
BEGIN
	--oPrimaryKeyName := utils.psp_obtener_pk(p_schemaName,p_tableName) ;
 
 
	oFilter :=   CHR(9) || utils.psp_generar_filtros( p_schemaName,p_tableName ) || ';';
	oSQLCommand 	:=  CHR(9) || ' DELETE FROM '||p_schemaName ||'.'||p_tableName || CHR(13) || CHR(10) || oFilter ;
	oParameterList 	:= utils.psp_generar_parametros(p_schemaName,p_tableName,1);
 
	oFunctionBody 	:= 'CREATE OR REPLACE FUNCTION ' ||p_schemaName||'.psd_'||p_tableName ||'(' || oParameterList ||')'  ;
	oFunctionBody := oFunctionBody  ;
 
	--- ENCABEZADO DE FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_encabezado();
	--Comando Funcion
	oFunctionBody := oFunctionBody || oSQLCommand || CHR(13) || CHR(10) ;
	--- PIES de FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_pies();
 
 
 
    EXECUTE ''||oFunctionBody ||'' ;
END;
$$;
 
 
ALTER FUNCTION utils.psp_crear_delete(p_schemaname character varying, p_tablename character varying) OWNER TO postgres;
 
--
-- TOC entry 459 (class 1255 OID 25009)
-- Name: psp_crear_insert(character varying, character varying); Type: FUNCTION; Schema: utils; Owner: postgres
--
 
CREATE FUNCTION psp_crear_insert(p_schemaname character varying, p_tablename character varying) RETURNS void
    LANGUAGE plpgsql
    AS $$
DECLARE
	oRecord 			RECORD;
	oTableDef			REFCURSOR;
 
	oFunctionBody		VARCHAR;
	oSQLCommand			VARCHAR;
	oParameterList		VARCHAR;
	oFieldNameList		VARCHAR;
	oParameterValues	VARCHAR;
	oPrimaryKeyName     VARCHAR;
	oTablaConIdioma     boolean;
 
BEGIN
	oParameterValues := utils.psp_generar_campos_parametros( p_schemaName,p_tableName );
 
	oFieldNameList := utils.psp_generar_campos( p_schemaName,p_tableName );
	oParameterList 	:= utils.psp_generar_parametros(p_schemaName,p_tableName,2);
 
	oSQLCommand := CHR(9) || ' INSERT INTO ' || p_schemaName || '.' || p_tableName || ' ( ' || oFieldNameList  || ' ) '||CHR(13) || CHR(10);
	oSQLCommand := oSQLCommand || CHR(9) || ' VALUES ' || ' ( ' || oParameterValues  || ' ); '||CHR(13) || CHR(10);
 
	oFunctionBody 	:= 'CREATE OR REPLACE FUNCTION ' ||p_schemaName||'.psi_'||p_tableName ||'(' || oParameterList ||')'  ;
	oFunctionBody   := oFunctionBody  ;
 
	--- ENCABEZADO DE FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_encabezado();
	--Comando Funcion
	oFunctionBody := oFunctionBody || oSQLCommand || CHR(13) || CHR(10) ;
	--- PIES de FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_pies();
 
    EXECUTE ''||oFunctionBody ||'' ;
END;
$$;
 
 
ALTER FUNCTION utils.psp_crear_insert(p_schemaname character varying, p_tablename character varying) OWNER TO postgres;
 
--
-- TOC entry 643 (class 1255 OID 25082)
-- Name: psp_crear_listar(character varying, character varying); Type: FUNCTION; Schema: utils; Owner: postgres
--
 
CREATE FUNCTION psp_crear_listar(p_schemaname character varying, p_tablename character varying) RETURNS void
    LANGUAGE plpgsql
    AS $$
DECLARE
	oRecord		RECORD;
	oTableDef	REFCURSOR;
 
	oFunctionBody 	    VARCHAR;
	oSQLCommand	    VARCHAR;
	oFilter		    VARCHAR;
	oParameterList	    VARCHAR;
	oFieldNameList	    VARCHAR;
	oPrimaryKeyName     VARCHAR;
 
	oOrder	    VARCHAR;
 
BEGIN
 
	oPrimaryKeyName := utils.psp_obtener_pk(p_schemaName,p_tableName) ;
	oOrder := oPrimaryKeyName ;
 
 
	--oParameterValues := utils.psp_generar_campos_parametros( p_schemaName,p_tableName );
 
	oFieldNameList := utils.psp_generar_campos( p_schemaName,p_tableName );
	oParameterList 	:= utils.psp_generar_parametros(p_schemaName,p_tableName,0);
 
	oSQLCommand :=  CHR(9) || '   SELECT ' || oFieldNameList || CHR(13) || CHR(10); --lista de campos
	oSQLCommand := oSQLCommand || CHR(9) || '   FROM ' ||p_schemaName ||'.'||p_tableName || CHR(13) || CHR(10);
 
	IF utils.psp_verificar_idioma(p_schemaName,p_tableName) THEN
		oSQLCommand := oSQLCommand || CHR(9) || ' WHERE id_idioma = p_id_idioma '  || CHR(13) || CHR(10);
	END IF;
 
	oSQLCommand := oSQLCommand || CHR(9) || '   ORDER BY ' || oOrder || ';' || CHR(13) || CHR(10);
 
 
	oFunctionBody 	:= 'CREATE OR REPLACE FUNCTION ' ||p_schemaName||'.pss_listar_'||p_tableName ||'(' || oParameterList ||')'  ;
	oFunctionBody   := oFunctionBody  ;
 
	--- ENCABEZADO DE FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_encabezado2();
	--Comando Funcion
	oFunctionBody := oFunctionBody || oSQLCommand || CHR(13) || CHR(10) ;
	--- PIES de FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_pies2();
 
    EXECUTE ''||oFunctionBody ||'' ;
 
END;
$$;
 
 
ALTER FUNCTION utils.psp_crear_listar(p_schemaname character varying, p_tablename character varying) OWNER TO postgres;
 
--
-- TOC entry 637 (class 1255 OID 26262)
-- Name: psp_crear_listar_id(character varying, character varying); Type: FUNCTION; Schema: utils; Owner: postgres
--
 
CREATE FUNCTION psp_crear_listar_id(p_schemaname character varying, p_tablename character varying) RETURNS void
    LANGUAGE plpgsql
    AS $$
DECLARE
	oRecord		RECORD;
	oTableDef	REFCURSOR;
 
	oFunctionBody 	    VARCHAR;
	oSQLCommand	    VARCHAR;
	oFilter		    VARCHAR;
	oParameterList	    VARCHAR;
	oFieldNameList	    VARCHAR;
	oPrimaryKeyName     VARCHAR;
 
	oOrder	    VARCHAR;
 
BEGIN
 
	oPrimaryKeyName := utils.psp_obtener_pk(p_schemaName,p_tableName) ;
	oOrder := oPrimaryKeyName ;
 
 
	--oParameterValues := utils.psp_generar_campos_parametros( p_schemaName,p_tableName );
 
	oFieldNameList := utils.psp_generar_campos( p_schemaName,p_tableName );
	oParameterList 	:= utils.psp_generar_parametros(p_schemaName,p_tableName,1);
	oFilter        := CHR(9) || utils.psp_generar_filtros( p_schemaName,p_tableName ) ;
 
 
	oSQLCommand :=  CHR(9) || '   SELECT ' || oFieldNameList || CHR(13) || CHR(10); --lista de campos
	oSQLCommand := oSQLCommand || CHR(9) || '   FROM ' ||p_schemaName ||'.'||p_tableName || CHR(13) || CHR(10);
 
	oSQLCommand := oSQLCommand || CHR(9) || oFilter || CHR(13) || CHR(10);
 
	oSQLCommand := oSQLCommand || CHR(9) || '   ORDER BY ' || oOrder || ';' || CHR(13) || CHR(10);
 
 
	oFunctionBody 	:= 'CREATE OR REPLACE FUNCTION ' ||p_schemaName||'.pss_listar_'||p_tableName || '_id' ||'(' || oParameterList ||')'  ;
	oFunctionBody   := oFunctionBody  ;
 
	--- ENCABEZADO DE FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_encabezado2();
	--Comando Funcion
	oFunctionBody := oFunctionBody || oSQLCommand || CHR(13) || CHR(10) ;
	--- PIES de FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_pies2();
 
    EXECUTE ''||oFunctionBody ||'' ;
 
END;
$$;
 
 
ALTER FUNCTION utils.psp_crear_listar_id(p_schemaname character varying, p_tablename character varying) OWNER TO postgres;
 
--
-- TOC entry 645 (class 1255 OID 26455)
-- Name: psp_crear_listar_pg(character varying, character varying); Type: FUNCTION; Schema: utils; Owner: postgres
--
 
CREATE FUNCTION psp_crear_listar_pg(p_schemaname character varying, p_tablename character varying) RETURNS void
    LANGUAGE plpgsql
    AS $$
DECLARE
	oRecord		RECORD;
	oTableDef	REFCURSOR;
 
	oFunctionBody 	    VARCHAR;
	oSQLCommand	    VARCHAR;
	oFilter		    VARCHAR;
	oParameterList	    VARCHAR;
	oFieldNameList	    VARCHAR;
	oPrimaryKeyName     VARCHAR;
 
	oOrder	    VARCHAR;
 
BEGIN
 
	oPrimaryKeyName := utils.psp_obtener_pk(p_schemaName,p_tableName) ;
	oOrder := oPrimaryKeyName ;
 
 
	--oParameterValues := utils.psp_generar_campos_parametros( p_schemaName,p_tableName );
 
	oFieldNameList := utils.psp_generar_campos( p_schemaName,p_tableName );
	oParameterList 	:= utils.psp_generar_parametros(p_schemaName,p_tableName,0);
 
	oSQLCommand :=  CHR(9) || '   SELECT ' || oFieldNameList || CHR(13) || CHR(10); --lista de campos
	oSQLCommand := oSQLCommand || CHR(9) || '   FROM ' ||p_schemaName ||'.'||p_tableName || CHR(13) || CHR(10);
 
	IF utils.psp_verificar_idioma(p_schemaName,p_tableName) THEN
		oSQLCommand := oSQLCommand || CHR(9) || ' WHERE id_idioma = p_id_idioma '  || CHR(13) || CHR(10);
	END IF;
 
	oSQLCommand := oSQLCommand || CHR(9) || '   ORDER BY ' || oOrder  || CHR(13) || CHR(10);
	oSQLCommand := oSQLCommand || CHR(9) || '   LIMIT p_cantidad_filas OFFSET p_desplazamiento  '  || ';' || CHR(13) || CHR(10);
 
 
 
 
	oFunctionBody 	:= 'CREATE OR REPLACE FUNCTION ' ||p_schemaName||'.pss_listar_'||p_tableName ||'_pg(' || oParameterList || ' , p_cantidad_filas integer, p_desplazamiento integer '  ||')'  ;
	oFunctionBody   := oFunctionBody  ;
 
	--- ENCABEZADO DE FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_encabezado2();
	--Comando Funcion
	oFunctionBody := oFunctionBody || oSQLCommand || CHR(13) || CHR(10) ;
	--- PIES de FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_pies2();
 
    EXECUTE ''||oFunctionBody ||'' ;
 
END;
$$;
 
 
ALTER FUNCTION utils.psp_crear_listar_pg(p_schemaname character varying, p_tablename character varying) OWNER TO postgres;
 
--
-- TOC entry 521 (class 1255 OID 25166)
-- Name: psp_crear_update(character varying, character varying); Type: FUNCTION; Schema: utils; Owner: postgres
--
 
CREATE FUNCTION psp_crear_update(p_schemaname character varying, p_tablename character varying) RETURNS void
    LANGUAGE plpgsql
    AS $$
DECLARE
	oRecord		RECORD;
	oTableDef	REFCURSOR;
 
	oFunctionBody 	    VARCHAR;
	oSQLCommand	    VARCHAR;
	oFilter		    VARCHAR;
	oParameterList	    VARCHAR;
	oFieldNameList	    VARCHAR;
	oPrimaryKeyName     VARCHAR;
 
BEGIN
 
	oParameterList 	:= '';
	oFieldNameList	:= '';
 
	oFieldNameList := CHR(9) || utils.psp_generar_asignaciones( p_schemaName,p_tableName );
	oFilter        := CHR(9) || utils.psp_generar_filtros( p_schemaName,p_tableName ) || ';';
 
	oSQLCommand    :=  CHR(9) || ' UPDATE '||p_schemaName ||'.'||p_tableName ||' SET ' ;
	oSQLCommand    :=  oSQLCommand || CHR(13) || CHR(10) || oFieldNameList || CHR(13) || CHR(10) || oFilter ;
 
 
	oParameterList 	:= utils.psp_generar_parametros(p_schemaName,p_tableName,2);
 
	oFunctionBody 	:= 'CREATE OR REPLACE FUNCTION ' ||p_schemaName||'.psu_'||p_tableName ||'(' || oParameterList ||')'  ;
	oFunctionBody   := oFunctionBody  ;
 
	--- ENCABEZADO DE FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_encabezado();
	--Comando Funcion
	oFunctionBody := oFunctionBody || oSQLCommand || CHR(13) || CHR(10) ;
	--- PIES de FUNCION
	oFunctionBody := oFunctionBody || utils.psp_obtener_pies();
 
	EXECUTE ''||oFunctionBody ||'' ;
END;
$$;
 
 
ALTER FUNCTION utils.psp_crear_update(p_schemaname character varying, p_tablename character varying) OWNER TO postgres;
 
--
-- TOC entry 430 (class 1255 OID 33405)
-- Name: psp_exportar_csv_utf8(text, text, text); Type: FUNCTION; Schema: utils; Owner: postgres
--
 
CREATE FUNCTION psp_exportar_csv_utf8(p_esquema text, p_tabla text, p_ruta text) RETURNS void
    LANGUAGE plpgsql
    AS $$
declare
	v_sql text;
begin
	v_sql := 'COPY ' || p_esquema || '.' || p_tabla ||' TO ' ||CHR(39)|| p_ruta ||CHR(39)|| ' DELIMITERS ' ||CHR(39)||','||CHR(39)||' WITH CSV';
	EXECUTE v_sql;
return;
end;
Valora esta pregunta
Me gusta: Está pregunta es útil y esta claraNo me gusta: Está pregunta no esta clara o no es útil
1
Responder