Kreditorenbewegungen.sql 12 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157
  1. select c112 as "Accounting Date",
  2. c154 as "Document Type",
  3. c153 as "Document Number",
  4. c152 as "Position In Document",
  5. c109 as "Nominal Account Number",
  6. c151 as "Customer Number",
  7. c150 as "Is Balanced",
  8. c149 as "Clearing Number",
  9. c148 as "Document Date",
  10. c147 as "Posted Value",
  11. c146 as "Debit Or Credit",
  12. c145 as "Posted Count",
  13. c144 as "Branch Number",
  14. c143 as "Customer Contra Account",
  15. c142 as "Nominal Contra Account",
  16. c141 as "Contra Account Text",
  17. c140 as "Account Form Page Number",
  18. c139 as "Account Form Page Line",
  19. c138 as "Serial Number Each Month",
  20. c137 as "Employee Number",
  21. c136 as "Invoice Date",
  22. c135 as "Invoice Number",
  23. c134 as "Dunning Level",
  24. c133 as "Last Dunning Date",
  25. c132 as "Journal Page",
  26. c131 as "Journal Line",
  27. c130 as "Cash Discount",
  28. c129 as "Term Of Payment",
  29. c128 as "Posting Text",
  30. c127 as "Vehicle Reference",
  31. c126 as "Vat Id Number",
  32. c125 as "Account Statement Number",
  33. c124 as "Account Statement Page",
  34. c123 as "Vat Key",
  35. c122 as "Days For Cash Discount",
  36. c121 as "Day Of Actual Accounting",
  37. c120 as "Skr51 Branch",
  38. c119 as "Skr51 Make",
  39. c118 as "Skr51 Cost Center",
  40. c117 as "Skr51 Sales Channel",
  41. c116 as "Skr51 Cost Unit",
  42. c115 as "Previously Used Account No",
  43. c114 as "Free Form Accounting Text",
  44. c113 as "Free Form Document Text",
  45. '1' as "Rechtseinheit",
  46. c85 as "Betrieb",
  47. c112 as "Bookkeep Date",
  48. c111 as "Text",
  49. '1' as "Mandant",
  50. c97 as "Betrag",
  51. c110 as "Menge",
  52. c109 as "Acct Nr",
  53. c83 as "Customer Number_suctomer_supplier",
  54. c108 as "Is Supplier",
  55. c107 as "First Name",
  56. c106 as "Family Name",
  57. c105 as "Document Type In Journal",
  58. c104 as "Document Type Description",
  59. SUM(c97) OVER (partition by c83) as "Debitorsaldo_",
  60. c103 as "Invoice Type_Invoices",
  61. c102 as "Invoice Number_Invoices",
  62. c101 as "Subsidiary_Invoices",
  63. c100 as "Invoice Date_Invoices",
  64. '1' as "Hauptbetrieb",
  65. c99 as "Standort_ori",
  66. c98 as "Sel Name",
  67. c97 as "OP-Saldo",
  68. c96 as "Kostenstelle",
  69. c95 as "Tage",
  70. c94 as "Staffel",
  71. c93 as "Kunde",
  72. c92 as "Beleg",
  73. c91 as "Employee Number_Employees_journal_accountings",
  74. c90 as "Name_Employees_journal_accountings",
  75. c89 as "Anzahl_Stellen_Invoice_Number",
  76. c88 as "Forderungsart_aus_erste_Stelle_Inv_Number",
  77. c87 as "Forderungsart",
  78. c86 as "Standort_aus_2_Stelle_Invoice_Number",
  79. c85 as "Standort",
  80. c84 as "Status Rechnung"
  81. from
  82. (select T3."customer_number" as c83,
  83. CASE WHEN (T1."clearing_number" = 0) THEN ('offen') ELSE ('bezahlt') END as c84,
  84. ('0' + ((convert(varchar(50), T1."branch_number")))) as c85,
  85. CASE WHEN ((((len(T1."invoice_number" + 'Z') - 1)) = 7) and ((substring(T1."invoice_number", 2, 1)) BETWEEN '1' AND '4')) THEN ('0' + (substring(T1."invoice_number", 2, 1))) ELSE null END as c86,
  86. CASE WHEN ((CASE WHEN (T5."invoice_type" IN (2,4,6,3)) THEN ('3') WHEN (T5."invoice_type" IN (5)) THEN ('6') WHEN (T5."invoice_type" IN (7)) THEN ('1') WHEN (T5."invoice_type" IN (8)) THEN ('2') WHEN (T4."document_type_in_journal" = 'R') THEN ('7') ELSE null END) = '1') THEN ('Neuwagen') WHEN ((CASE WHEN (T5."invoice_type" IN (2,4,6,3)) THEN ('3') WHEN (T5."invoice_type" IN (5)) THEN ('6') WHEN (T5."invoice_type" IN (7)) THEN ('1') WHEN (T5."invoice_type" IN (8)) THEN ('2') WHEN (T4."document_type_in_journal" = 'R') THEN ('7') ELSE null END) = '2') THEN ('Gebrauchtwagen') WHEN ((CASE WHEN (T5."invoice_type" IN (2,4,6,3)) THEN ('3') WHEN (T5."invoice_type" IN (5)) THEN ('6') WHEN (T5."invoice_type" IN (7)) THEN ('1') WHEN (T5."invoice_type" IN (8)) THEN ('2') WHEN (T4."document_type_in_journal" = 'R') THEN ('7') ELSE null END) = '3') THEN ('Service') WHEN ((CASE WHEN (T5."invoice_type" IN (2,4,6,3)) THEN ('3') WHEN (T5."invoice_type" IN (5)) THEN ('6') WHEN (T5."invoice_type" IN (7)) THEN ('1') WHEN (T5."invoice_type" IN (8)) THEN ('2') WHEN (T4."document_type_in_journal" = 'R') THEN ('7') ELSE null END) = '6') THEN ('Teile') ELSE ('nicht zuzuordnen') END as c87,
  87. CASE WHEN ((((len(T1."invoice_number" + 'Z') - 1)) = 7) and ((left(T1."invoice_number",1)) IN ('2','3','4'))) THEN ('Service') WHEN ((((len(T1."invoice_number" + 'Z') - 1)) = 7) and ((left(T1."invoice_number",1)) IN ('5'))) THEN ('Teile') WHEN ((((len(T1."invoice_number" + 'Z') - 1)) = 7) and ((left(T1."invoice_number",1)) IN ('6'))) THEN ('Garantie') WHEN ((((len(T1."invoice_number" + 'Z') - 1)) = 7) and ((left(T1."invoice_number",1)) IN ('7'))) THEN ('Neuwagen') WHEN ((((len(T1."invoice_number" + 'Z') - 1)) = 7) and ((left(T1."invoice_number",1)) IN ('8'))) THEN ('Gebrauchtwagen') WHEN (T1."document_type" = 'R') THEN ('Rent') ELSE ('nicht zuzuordnen') END as c88,
  88. (len(T1."invoice_number" + 'Z') - 1) as c89,
  89. T2."name" as c90,
  90. T2."employee_number" as c91,
  91. CASE WHEN (T1."posting_text" IS NOT NULL) THEN ((left(((convert(varchar(50), T1."document_number"))))) + ' - ' + T1."posting_text" + ' - ' + (convert(varchar(50), year(T1."document_date")) + '-' + convert(varchar(50), month(T1."document_date")) + '-' + convert(varchar(50), day(T1."document_date")))) ELSE ((convert(varchar(50), year(T1."document_date")) + '-' + convert(varchar(50), month(T1."document_date")) + '-' + convert(varchar(50), day(T1."document_date")))) END as c92,
  92. ((left(((convert(varchar(50), T3."customer_number"))))) + ' - ' + T3."first_name" + ' ' + T3."family_name") as c93,
  93. CASE WHEN (((day((getdate()) - (convert(datetime, T1."accounting_date"))))) BETWEEN 0 AND 14) THEN ('< 2 Wochen') WHEN (((day((getdate()) - (convert(datetime, T1."accounting_date"))))) BETWEEN 15 AND 28) THEN ('2 - 4 Wochen') WHEN (((day((getdate()) - (convert(datetime, T1."accounting_date"))))) BETWEEN 29 AND 42) THEN ('4 - 6 Wochen') WHEN (((day((getdate()) - (convert(datetime, T1."accounting_date"))))) BETWEEN 43 AND 84) THEN ('6 - 12 Wochen') WHEN (((day((getdate()) - (convert(datetime, T1."accounting_date"))))) > 84) THEN ('> 12 Wochen') ELSE null END as c94,
  94. (day((getdate()) - (convert(datetime, T1."accounting_date")))) as c95,
  95. CASE WHEN (T5."invoice_type" IN (2,4,6,3)) THEN ('3') WHEN (T5."invoice_type" IN (5)) THEN ('6') WHEN (T5."invoice_type" IN (7)) THEN ('1') WHEN (T5."invoice_type" IN (8)) THEN ('2') WHEN (T4."document_type_in_journal" = 'R') THEN ('7') ELSE null END as c96,
  96. (CASE WHEN (T1."debit_or_credit" = 'H') THEN (T1."posted_value" / 100) ELSE (T1."posted_value" / 100 * -1) END) as c97,
  97. (left(((convert(varchar(50), T2."employee_number"))))) + ' - ' + T2."name" as c98,
  98. CASE WHEN (T5."subsidiary" IS NOT NULL) THEN ('0' + (left(((convert(varchar(50), T5."subsidiary")))))) ELSE ('nicht zuzuordnen') END as c99,
  99. T5."invoice_date" as c100,
  100. T5."subsidiary" as c101,
  101. T5."invoice_number" as c102,
  102. T5."invoice_type" as c103,
  103. T4."document_type_description" as c104,
  104. T4."document_type_in_journal" as c105,
  105. T3."family_name" as c106,
  106. T3."first_name" as c107,
  107. T3."is_supplier" as c108,
  108. T1."nominal_account_number" as c109,
  109. CASE WHEN (T1."debit_or_credit" = 'H') THEN (T1."posted_count" / 100 * -1) ELSE (T1."posted_count" / 100) END as c110,
  110. ((rtrim(((convert(varchar(50), T1."document_number"))))) + ' - ' + T1."invoice_number" + ' - ' + T1."posting_text" + '/' + T1."vehicle_reference" + ' - ' + ((left(((convert(varchar(50), T2."employee_number"))))) + ' - ' + T2."name") + ' - ' + (convert(varchar(50), year(T1."document_date")) + '-' + convert(varchar(50), month(T1."document_date")) + '-' + convert(varchar(50), day(T1."document_date")))) as c111,
  111. T1."accounting_date" as c112,
  112. CASE WHEN ((((((((rtrim(((convert(varchar(50), T1."document_number"))))) + ' - ' + T1."invoice_number" + ' - ' + T1."posting_text" + '/' + T1."vehicle_reference" + ' - ' + ((left(((convert(varchar(50), T2."employee_number"))))) + ' - ' + T2."name") + ' - ' + (convert(varchar(50), year(T1."document_date")) + '-' + convert(varchar(50), month(T1."document_date")) + '-' + convert(varchar(50), day(T1."document_date"))))) LIKE '%RG-BONUS%') or ((((rtrim(((convert(varchar(50), T1."document_number"))))) + ' - ' + T1."invoice_number" + ' - ' + T1."posting_text" + '/' + T1."vehicle_reference" + ' - ' + ((left(((convert(varchar(50), T2."employee_number"))))) + ' - ' + T2."name") + ' - ' + (convert(varchar(50), year(T1."document_date")) + '-' + convert(varchar(50), month(T1."document_date")) + '-' + convert(varchar(50), day(T1."document_date"))))) LIKE '%GEBURTSTAGS%')) or ((((rtrim(((convert(varchar(50), T1."document_number"))))) + ' - ' + T1."invoice_number" + ' - ' + T1."posting_text" + '/' + T1."vehicle_reference" + ' - ' + ((left(((convert(varchar(50), T2."employee_number"))))) + ' - ' + T2."name") + ' - ' + (convert(varchar(50), year(T1."document_date")) + '-' + convert(varchar(50), month(T1."document_date")) + '-' + convert(varchar(50), day(T1."document_date"))))) LIKE '%STARTGUTHABEN%')) or ((((rtrim(((convert(varchar(50), T1."document_number"))))) + ' - ' + T1."invoice_number" + ' - ' + T1."posting_text" + '/' + T1."vehicle_reference" + ' - ' + ((left(((convert(varchar(50), T2."employee_number"))))) + ' - ' + T2."name") + ' - ' + (convert(varchar(50), year(T1."document_date")) + '-' + convert(varchar(50), month(T1."document_date")) + '-' + convert(varchar(50), day(T1."document_date"))))) LIKE '%BONUS F%')) or ((((rtrim(((convert(varchar(50), T1."document_number"))))) + ' - ' + T1."invoice_number" + ' - ' + T1."posting_text" + '/' + T1."vehicle_reference" + ' - ' + ((left(((convert(varchar(50), T2."employee_number"))))) + ' - ' + T2."name") + ' - ' + (convert(varchar(50), year(T1."document_date")) + '-' + convert(varchar(50), month(T1."document_date")) + '-' + convert(varchar(50), day(T1."document_date"))))) LIKE '%RG-ABZUG%')) THEN ('Bonus/Startguthaben') ELSE ('ohne Bonus/Startguthaben') END as c113,
  113. T1."free_form_accounting_text" as c114,
  114. T1."previously_used_account_no" as c115,
  115. T1."skr51_cost_unit" as c116,
  116. T1."skr51_sales_channel" as c117,
  117. T1."skr51_cost_center" as c118,
  118. T1."skr51_make" as c119,
  119. T1."skr51_branch" as c120,
  120. T1."day_of_actual_accounting" as c121,
  121. T1."days_for_cash_discount" as c122,
  122. T1."vat_key" as c123,
  123. T1."account_statement_page" as c124,
  124. T1."account_statement_number" as c125,
  125. T1."vat_id_number" as c126,
  126. T1."vehicle_reference" as c127,
  127. T1."posting_text" as c128,
  128. T1."term_of_payment" as c129,
  129. T1."cash_discount" as c130,
  130. T1."journal_line" as c131,
  131. T1."journal_page" as c132,
  132. T1."last_dunning_date" as c133,
  133. T1."dunning_level" as c134,
  134. T1."invoice_number" as c135,
  135. T1."invoice_date" as c136,
  136. T1."employee_number" as c137,
  137. T1."serial_number_each_month" as c138,
  138. T1."account_form_page_line" as c139,
  139. T1."account_form_page_number" as c140,
  140. T1."contra_account_text" as c141,
  141. T1."nominal_contra_account" as c142,
  142. T1."customer_contra_account" as c143,
  143. T1."branch_number" as c144,
  144. T1."posted_count" as c145,
  145. T1."debit_or_credit" as c146,
  146. T1."posted_value" as c147,
  147. T1."document_date" as c148,
  148. T1."clearing_number" as c149,
  149. T1."is_balanced" as c150,
  150. T1."customer_number" as c151,
  151. T1."position_in_document" as c152,
  152. T1."document_number" as c153,
  153. T1."document_type" as c154
  154. from (((("journal_accountings" T1 left outer join "LOCOSOFT"."dbo"."employees" T2 on T1."employee_number" = T2."employee_number") left outer join "LOCOSOFT"."dbo"."customers_suppliers" T3 on T3."customer_number" = T1."customer_number") left outer join "document_types" T4 on T4."document_type_in_journal" = T1."document_type") left outer join "invoices" T5 on T5."invtype_invnr" = T1."invoice_number")
  155. where ((((T1."nominal_account_number" IN (1600,1610)) and (T1."customer_number" IS NOT NULL)) and (T3."customer_number" IS NOT NULL)) and (T1."document_type" IN ('W','E','L')))
  156. ) D1
  157. -- order by "Customer Number" asc,"Invoice Number" asc,"Document Type In Journal" asc,"Nominal Account Number" asc