pgsql.sql 4.8 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153
  1. CREATE OR REPLACE FUNCTION pgsql_type(a_type varchar) RETURNS varchar AS
  2. $BODY$
  3. DECLARE
  4. v_type varchar;
  5. BEGIN
  6. IF a_type='int8' THEN
  7. v_type:='bigint';
  8. ELSIF a_type='int4' THEN
  9. v_type:='integer';
  10. ELSIF a_type='int2' THEN
  11. v_type:='smallint';
  12. ELSIF a_type='bpchar' THEN
  13. v_type:='char';
  14. ELSE
  15. v_type:=a_type;
  16. END IF;
  17. RETURN v_type;
  18. END;
  19. $BODY$
  20. LANGUAGE PLPGSQL;
  21. CREATE TYPE "public"."tablestruct" AS (
  22. "fields_key_name" varchar(100),
  23. "fields_name" VARCHAR(200),
  24. "fields_type" VARCHAR(20),
  25. "fields_length" BIGINT,
  26. "fields_not_null" VARCHAR(10),
  27. "fields_default" VARCHAR(500),
  28. "fields_comment" VARCHAR(1000)
  29. );
  30. CREATE OR REPLACE FUNCTION "public"."table_msg" (a_schema_name varchar, a_table_name varchar) RETURNS SETOF "public"."tablestruct" AS
  31. $body$
  32. DECLARE
  33. v_ret tablestruct;
  34. v_oid oid;
  35. v_sql varchar;
  36. v_rec RECORD;
  37. v_key varchar;
  38. v_conkey smallint[];
  39. v_pk varchar[];
  40. v_len smallint;
  41. v_pos smallint := 1;
  42. BEGIN
  43. SELECT
  44. pg_class.oid INTO v_oid
  45. FROM
  46. pg_class
  47. INNER JOIN pg_namespace ON (pg_class.relnamespace = pg_namespace.oid AND lower(pg_namespace.nspname) = a_schema_name)
  48. WHERE
  49. pg_class.relname=a_table_name;
  50. IF NOT FOUND THEN
  51. RETURN;
  52. END IF;
  53. SELECT
  54. pg_constraint.conkey INTO v_conkey
  55. FROM
  56. pg_constraint
  57. INNER JOIN pg_class ON pg_constraint.conrelid = pg_class.oid
  58. INNER JOIN pg_attribute ON pg_attribute.attrelid = pg_class.oid
  59. INNER JOIN pg_type ON pg_type.oid = pg_attribute.atttypid
  60. WHERE
  61. pg_class.relname = a_table_name
  62. AND pg_constraint.contype = 'p';
  63. v_len := array_length(v_conkey,1) + 1;
  64. WHILE v_pos < v_len LOOP
  65. SELECT
  66. pg_attribute.attname INTO v_key
  67. FROM pg_constraint
  68. INNER JOIN pg_class ON pg_constraint.conrelid = pg_class.oid
  69. INNER JOIN pg_attribute ON pg_attribute.attrelid = pg_class.oid AND pg_attribute.attnum = pg_constraint.conkey [ v_conkey[v_pos] ]
  70. INNER JOIN pg_type ON pg_type.oid = pg_attribute.atttypid
  71. WHERE pg_class.relname = a_table_name AND pg_constraint.contype = 'p';
  72. v_pk := array_append(v_pk,v_key);
  73. v_pos := v_pos + 1;
  74. END LOOP;
  75. v_sql='
  76. SELECT
  77. pg_attribute.attname AS fields_name,
  78. pg_attribute.attnum AS fields_index,
  79. pgsql_type(pg_type.typname::varchar) AS fields_type,
  80. pg_attribute.atttypmod-4 as fields_length,
  81. CASE WHEN pg_attribute.attnotnull THEN ''not null''
  82. ELSE ''''
  83. END AS fields_not_null,
  84. pg_attrdef.adsrc AS fields_default,
  85. pg_description.description AS fields_comment
  86. FROM
  87. pg_attribute
  88. INNER JOIN pg_class ON pg_attribute.attrelid = pg_class.oid
  89. INNER JOIN pg_type ON pg_attribute.atttypid = pg_type.oid
  90. LEFT OUTER JOIN pg_attrdef ON pg_attrdef.adrelid = pg_class.oid AND pg_attrdef.adnum = pg_attribute.attnum
  91. LEFT OUTER JOIN pg_description ON pg_description.objoid = pg_class.oid AND pg_description.objsubid = pg_attribute.attnum
  92. WHERE
  93. pg_attribute.attnum > 0
  94. AND attisdropped <> ''t''
  95. AND pg_class.oid = ' || v_oid || '
  96. ORDER BY pg_attribute.attnum' ;
  97. FOR v_rec IN EXECUTE v_sql LOOP
  98. v_ret.fields_name=v_rec.fields_name;
  99. v_ret.fields_type=v_rec.fields_type;
  100. IF v_rec.fields_length > 0 THEN
  101. v_ret.fields_length:=v_rec.fields_length;
  102. ELSE
  103. v_ret.fields_length:=NULL;
  104. END IF;
  105. v_ret.fields_not_null=v_rec.fields_not_null;
  106. v_ret.fields_default=v_rec.fields_default;
  107. v_ret.fields_comment=v_rec.fields_comment;
  108. v_ret.fields_key_name='';
  109. v_len := array_length(v_pk,1) + 1;
  110. v_pos := 1;
  111. WHILE v_pos < v_len LOOP
  112. IF v_rec.fields_name = v_pk[v_pos] THEN
  113. v_ret.fields_key_name=v_pk[v_pos];
  114. EXIT;
  115. END IF;
  116. v_pos := v_pos + 1;
  117. END LOOP;
  118. RETURN NEXT v_ret;
  119. END LOOP;
  120. RETURN ;
  121. END;
  122. $body$
  123. LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
  124. COMMENT ON FUNCTION "public"."table_msg"(a_schema_name varchar, a_table_name varchar)
  125. IS '获得表信息';
  126. ---重载一个函数
  127. CREATE OR REPLACE FUNCTION "public"."table_msg" (a_table_name varchar) RETURNS SETOF "public"."tablestruct" AS
  128. $body$
  129. DECLARE
  130. v_ret tablestruct;
  131. BEGIN
  132. FOR v_ret IN SELECT * FROM table_msg('public',a_table_name) LOOP
  133. RETURN NEXT v_ret;
  134. END LOOP;
  135. RETURN;
  136. END;
  137. $body$
  138. LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
  139. COMMENT ON FUNCTION "public"."table_msg"(a_table_name varchar)
  140. IS '获得表信息';