|
| 1 | +SET SEARCH_PATH to pgstac, public; |
| 2 | +set check_function_bodies = off; |
| 3 | + |
| 4 | +CREATE OR REPLACE FUNCTION pgstac.cql2_query(j jsonb, recursion integer DEFAULT 0) |
| 5 | + RETURNS text |
| 6 | + LANGUAGE plpgsql |
| 7 | +AS $function$ |
| 8 | +DECLARE |
| 9 | +args jsonb := j->'args'; |
| 10 | +jtype text := jsonb_typeof(j->'args'); |
| 11 | +op text := lower(j->>'op'); |
| 12 | +arg jsonb; |
| 13 | +argtext text; |
| 14 | +argstext text[] := '{}'::text[]; |
| 15 | +inobj jsonb; |
| 16 | +_numeric text := ''; |
| 17 | +ops jsonb := |
| 18 | + '{ |
| 19 | + "eq": "%s = %s", |
| 20 | + "lt": "%s < %s", |
| 21 | + "lte": "%s <= %s", |
| 22 | + "gt": "%s > %s", |
| 23 | + "gte": "%s >= %s", |
| 24 | + "le": "%s <= %s", |
| 25 | + "ge": "%s >= %s", |
| 26 | + "=": "%s = %s", |
| 27 | + "<": "%s < %s", |
| 28 | + "<=": "%s <= %s", |
| 29 | + ">": "%s > %s", |
| 30 | + ">=": "%s >= %s", |
| 31 | + "like": "%s LIKE %s", |
| 32 | + "ilike": "%s ILIKE %s", |
| 33 | + "+": "%s + %s", |
| 34 | + "-": "%s - %s", |
| 35 | + "*": "%s * %s", |
| 36 | + "/": "%s / %s", |
| 37 | + "in": "%s = ANY (%s)", |
| 38 | + "not": "NOT (%s)", |
| 39 | + "between": "%s BETWEEN (%2$s)[1] AND (%2$s)[2]", |
| 40 | + "lower":" lower(%s)", |
| 41 | + "upper":" upper(%s)", |
| 42 | + "isnull": "%s IS NULL" |
| 43 | + }'::jsonb; |
| 44 | +ret text; |
| 45 | + |
| 46 | +BEGIN |
| 47 | +RAISE NOTICE 'j: %s', j; |
| 48 | +IF j ? 'filter' THEN |
| 49 | + RETURN cql2_query(j->'filter'); |
| 50 | +END IF; |
| 51 | + |
| 52 | +IF j ? 'upper' THEN |
| 53 | +RAISE NOTICE 'upper %s',jsonb_build_object( |
| 54 | + 'op', 'upper', |
| 55 | + 'args', jsonb_build_array( j-> 'upper') |
| 56 | + ) ; |
| 57 | + RETURN cql2_query( |
| 58 | + jsonb_build_object( |
| 59 | + 'op', 'upper', |
| 60 | + 'args', jsonb_build_array( j-> 'upper') |
| 61 | + ) |
| 62 | + ); |
| 63 | +END IF; |
| 64 | + |
| 65 | +IF j ? 'lower' THEN |
| 66 | + RETURN cql2_query( |
| 67 | + jsonb_build_object( |
| 68 | + 'op', 'lower', |
| 69 | + 'args', jsonb_build_array( j-> 'lower') |
| 70 | + ) |
| 71 | + ); |
| 72 | +END IF; |
| 73 | + |
| 74 | +IF j ? 'args' AND jsonb_typeof(args) != 'array' THEN |
| 75 | + args := jsonb_build_array(args); |
| 76 | +END IF; |
| 77 | +-- END Cases where no further nesting is expected |
| 78 | +IF j ? 'op' THEN |
| 79 | + -- Special case to use JSONB index for equality |
| 80 | + IF op IN ('eq', '=') |
| 81 | + AND args->0 ? 'property' |
| 82 | + AND jsonb_typeof(args->1) IN ('number', 'string') |
| 83 | + AND (items_path(args->0->>'property')).eq IS NOT NULL |
| 84 | + THEN |
| 85 | + RETURN format((items_path(args->0->>'property')).eq, args->1); |
| 86 | + END IF; |
| 87 | + |
| 88 | + -- Temporal Query |
| 89 | + IF op ilike 't_%' or op = 'anyinteracts' THEN |
| 90 | + RETURN temporal_op_query(op, args); |
| 91 | + END IF; |
| 92 | + |
| 93 | + -- Spatial Query |
| 94 | + IF op ilike 's_%' or op = 'intersects' THEN |
| 95 | + RETURN spatial_op_query(op, args); |
| 96 | + END IF; |
| 97 | + |
| 98 | + -- In Query - separate into separate eq statements so that we can use eq jsonb optimization |
| 99 | + IF op = 'in' THEN |
| 100 | + RAISE NOTICE '% IN args: %', repeat(' ', recursion), args; |
| 101 | + SELECT INTO inobj |
| 102 | + jsonb_agg( |
| 103 | + jsonb_build_object( |
| 104 | + 'op', 'eq', |
| 105 | + 'args', jsonb_build_array( args->0 , v) |
| 106 | + ) |
| 107 | + ) |
| 108 | + FROM jsonb_array_elements( args->1) v; |
| 109 | + RETURN cql2_query(jsonb_build_object('op','or','args',inobj)); |
| 110 | + END IF; |
| 111 | +END IF; |
| 112 | + |
| 113 | +IF j ? 'property' THEN |
| 114 | + RETURN (items_path(j->>'property')).path_txt; |
| 115 | +END IF; |
| 116 | + |
| 117 | +IF j ? 'timestamp' THEN |
| 118 | + RETURN quote_literal(j->>'timestamp'); |
| 119 | +END IF; |
| 120 | + |
| 121 | +RAISE NOTICE '%jtype: %',repeat(' ', recursion), jtype; |
| 122 | +IF jsonb_typeof(j) = 'number' THEN |
| 123 | + RETURN format('%L::numeric', j->>0); |
| 124 | +END IF; |
| 125 | + |
| 126 | +IF jsonb_typeof(j) = 'string' THEN |
| 127 | + RETURN quote_literal(j->>0); |
| 128 | +END IF; |
| 129 | + |
| 130 | +IF jsonb_typeof(j) = 'array' THEN |
| 131 | + IF j @? '$[*] ? (@.type() == "number")' THEN |
| 132 | + RETURN CONCAT(quote_literal(textarr(j)::text), '::numeric[]'); |
| 133 | + ELSE |
| 134 | + RETURN CONCAT(quote_literal(textarr(j)::text), '::text[]'); |
| 135 | + END IF; |
| 136 | +END IF; |
| 137 | +RAISE NOTICE 'ARGS after array cleaning: %', args; |
| 138 | + |
| 139 | +RAISE NOTICE '%beforeargs op: %, args: %',repeat(' ', recursion), op, args; |
| 140 | +IF j ? 'args' THEN |
| 141 | + FOR arg in SELECT * FROM jsonb_array_elements(args) LOOP |
| 142 | + argtext := cql2_query(arg, recursion + 1); |
| 143 | + RAISE NOTICE '% -- arg: %, argtext: %', repeat(' ', recursion), arg, argtext; |
| 144 | + argstext := argstext || argtext; |
| 145 | + END LOOP; |
| 146 | +END IF; |
| 147 | +RAISE NOTICE '%afterargs op: %, argstext: %',repeat(' ', recursion), op, argstext; |
| 148 | + |
| 149 | + |
| 150 | +IF op IN ('and', 'or') THEN |
| 151 | + RAISE NOTICE 'inand op: %, argstext: %', op, argstext; |
| 152 | + SELECT |
| 153 | + concat(' ( ',array_to_string(array_agg(e), concat(' ',op,' ')),' ) ') |
| 154 | + INTO ret |
| 155 | + FROM unnest(argstext) e; |
| 156 | + RETURN ret; |
| 157 | +END IF; |
| 158 | + |
| 159 | +IF ops ? op THEN |
| 160 | + IF argstext[2] ~* 'numeric' THEN |
| 161 | + argstext := ARRAY[concat('(',argstext[1],')::numeric')] || argstext[2:3]; |
| 162 | + END IF; |
| 163 | + RETURN format(concat('(',ops->>op,')'), VARIADIC argstext); |
| 164 | +END IF; |
| 165 | + |
| 166 | +RAISE NOTICE '%op: %, argstext: %',repeat(' ', recursion), op, argstext; |
| 167 | + |
| 168 | +RETURN NULL; |
| 169 | +END; |
| 170 | +$function$ |
| 171 | +; |
| 172 | + |
| 173 | + |
| 174 | + |
| 175 | +SELECT set_version('0.4.3'); |
0 commit comments