summaryrefslogtreecommitdiff
path: root/sql/modules/Drafts.sql
blob: c2fc5abb1ca1bb96f1ea770918e0c592e289dd37 (plain)
  1. CREATE TYPE draft_search_result AS (
  2. id int,
  3. transdate date,
  4. reference text,
  5. description text,
  6. amount numeric
  7. );
  8. CREATE OR REPLACE FUNCTION draft__search(in_type text, in_with_accno text,
  9. in_from_date date, in_to_date date, in_amount_le numeric, in_amount_ge numeric)
  10. returns setof draft_search_result AS
  11. $$
  12. DECLARE out_row RECORD;
  13. BEGIN
  14. FOR out_row IN
  15. SELECT trans.id, trans.transdate, trans.reference,
  16. trans.description,
  17. sum(case when in_type = 'ap' AND chart.link = 'AP'
  18. THEN line.amount
  19. WHEN in_type = 'ar' AND chart.link = 'AR'
  20. THEN line.amount * -1
  21. WHEN in_type = 'gl' AND line.amount > 0
  22. THEN line.amount
  23. ELSE 0
  24. END) as amount
  25. FROM (
  26. SELECT id, transdate, invnumber as reference,
  27. description, approved from ap
  28. WHERE in_type = 'ap'
  29. UNION
  30. SELECT id, transdate, invnumber as reference,
  31. description, approved from ar
  32. WHERE in_type = 'ar'
  33. UNION
  34. SELECT id, transdate, reference, description,
  35. approved from gl
  36. WHERE in_type = 'gl'
  37. ) trans
  38. JOIN acc_trans line ON (trans.id = line.trans_id)
  39. JOIN chart ON (line.chart_id = chart.id)
  40. WHERE (in_from_date IS NULL or trans.transdate >= in_from_date)
  41. AND (in_to_date IS NULL
  42. or trans.transdate <= in_to_date)
  43. AND trans.approved IS FALSE
  44. AND trans.id NOT IN (select trans_id from voucher)
  45. GROUP BY trans.id, trans.transdate, trans.description
  46. HAVING (in_with_accno IS NULL or in_with_accno =
  47. ANY(as_array(chart.accno)))
  48. LOOP
  49. RETURN NEXT out_row;
  50. END LOOP;
  51. END;
  52. $$ language plpgsql;
  53. CREATE OR REPLACE FUNCTION draft_approve(in_id int) returns bool as
  54. $$
  55. declare
  56. t_table text;
  57. begin
  58. SELECT table_name into t_table FROM transactions where id = in_id;
  59. IF (t_table = 'ar') THEN
  60. UPDATE ar set approved = true where id = in_id;
  61. ELSIF (t_table = 'ap') THEN
  62. UPDATE ap set approved = true where id = in_id;
  63. ELSIF (t_table = 'gl') THEN
  64. UPDATE gl set approved = true where id = in_id;
  65. ELSE
  66. raise exception 'Invalid table % in draft_approve for transaction %', t_table, in_id;
  67. END IF;
  68. IF NOT FOUND THEN
  69. RETURN FALSE;
  70. END IF;
  71. UPDATE transactions
  72. SET approved_by =
  73. (select entity_id FROM users
  74. WHERE username = SESSION_USER),
  75. approved_at = now()
  76. WHERE id = in_id;
  77. RETURN TRUE;
  78. END;
  79. $$ LANGUAGE PLPGSQL SECURITY DEFINER;
  80. CREATE OR REPLACE FUNCTION draft_delete(in_id int) returns bool as
  81. $$
  82. declare
  83. t_table text;
  84. begin
  85. SELECT table_name into t_table FROM transactions where id = in_id;
  86. IF t_table = 'ar' THEN
  87. DELETE FROM ar WHERE id = in_id AND approved IS FALSE;
  88. ELSIF t_table = 'ap' THEN
  89. DELETE FROM ap WHERE id = in_id AND approved IS FALSE;
  90. ELSIF t_table = 'gl' THEN
  91. DELETE FROM gl WHERE id = in_id AND approved IS FALSE;
  92. ELSE
  93. raise exception 'Invalid table % in draft_delete for transaction %', t_table, in_id;
  94. END IF;
  95. RETURN FOUND;
  96. END;
  97. $$ LANGUAGE PLPGSQL SECURITY DEFINER;